2 Frequently Asked Questions (FAQ) for PostgreSQL
4 Last updated: Tue Sep 23 16:19:49 EDT 2008
6 Current maintainer: Bruce Momjian (bruce@momjian.us)
8 The most recent version of this document can be viewed at
9 http://www.postgresql.org/files/documentation/faqs/FAQ.html.
11 Platform-specific questions are answered at
12 http://www.postgresql.org/docs/faq/.
13 _________________________________________________________________
17 1.1) What is PostgreSQL? How is it pronounced? What is Postgres?
18 1.2) Who controls PostgreSQL?
19 1.3) What is the copyright of PostgreSQL?
20 1.4) What platforms does PostgreSQL support?
21 1.5) Where can I get PostgreSQL?
22 1.6) What is the most recent release?
23 1.7) Where can I get support?
24 1.8) How do I submit a bug report?
25 1.9) How do I find out about known bugs or missing features?
26 1.10) What documentation is available?
27 1.11) How can I learn SQL?
28 1.12) How do I submit a patch or join the development team?
29 1.13) How does PostgreSQL compare to other DBMSs? Can PostgreSQL be
31 1.14) Will PostgreSQL handle recent daylight saving time changes in
33 1.15) How do I unsubscribe from the PostgreSQL email lists? How do I
34 avoid receiving duplicate emails?
38 2.1) What interfaces are available for PostgreSQL?
39 2.2) What tools are available for using PostgreSQL with Web pages?
40 2.3) Does PostgreSQL have a graphical user interface?
42 Administrative Questions
44 3.1) How do I install PostgreSQL somewhere other than
46 3.2) How do I control connections from other hosts?
47 3.3) How do I tune the database engine for better performance?
48 3.4) What debugging features are available?
49 3.5) Why do I get "Sorry, too many clients" when trying to connect?
50 3.6 What is the upgrade process for PostgreSQL?
51 3.7) What computer hardware should I use?
55 4.1) How do I SELECT only the first few rows of a query? A random row?
56 4.2) How do I find out what tables, indexes, databases, and users are
57 defined? How do I see the queries used by psql to display them?
58 4.3) How do you change a column's data type?
59 4.4) What is the maximum size for a row, a table, and a database?
60 4.5) How much database disk space is required to store data from a
62 4.6) Why are my queries slow? Why don't they use my indexes?
63 4.7) How do I see how the query optimizer is evaluating my query?
64 4.8) How do I perform regular expression searches and case-insensitive
65 regular expression searches? How do I use an index for
66 case-insensitive searches?
67 4.9) In a query, how do I detect if a field is NULL? How do I
68 concatenate possible NULLs? How can I sort on whether a field is NULL
70 4.10) What is the difference between the various character types?
71 4.11.1) How do I create a serial/auto-incrementing field?
72 4.11.2) How do I get the value of a SERIAL insert?
73 4.11.3) Doesn't currval() lead to a race condition with other users?
74 4.11.4) Why aren't my sequence numbers reused on transaction abort?
75 Why are there gaps in the numbering of my sequence/SERIAL column?
76 4.12) What is an OID? What is a CTID?
77 4.13) Why do I get the error "ERROR: Memory exhausted in
79 4.14) How do I tell what PostgreSQL version I am running?
80 4.15) How do I create a column that will default to the current time?
81 4.16) How do I perform an outer join?
82 4.17) How do I perform queries using multiple databases?
83 4.18) How do I return multiple rows or columns from a function?
84 4.19) Why do I get "relation with OID ##### does not exist" errors
85 when accessing temporary tables in PL/PgSQL functions?
86 4.20) What replication solutions are available?
87 4.21) Why are my table and column names not recognized in my query?
88 Why is capitalization not preserved?
89 _________________________________________________________________
93 1.1) What is PostgreSQL? How is it pronounced? What is Postgres?
95 PostgreSQL is pronounced Post-Gres-Q-L. (For those curious about how
96 to say "PostgreSQL", an audio file is available.)
98 PostgreSQL is an object-relational database system that has the
99 features of traditional commercial database systems with enhancements
100 to be found in next-generation DBMS systems. PostgreSQL is free and
101 the complete source code is available.
103 PostgreSQL development is performed by a team of mostly volunteer
104 developers spread throughout the world and communicating via the
105 Internet. It is a community project and is not controlled by any
106 company. To get involved, see the developer's FAQ at
107 http://www.postgresql.org/docs/faqs.FAQ_DEV.html
109 Postgres is a widely-used nickname for PostgreSQL. It was the original
110 name of the project at Berkeley and is strongly preferred over other
111 nicknames. If you find 'PostgreSQL' hard to pronounce, call it
114 1.2) Who controls PostgreSQL?
116 If you are looking for a PostgreSQL gatekeeper, central committee, or
117 controlling company, give up --- there isn't one. We do have a core
118 committee and CVS committers, but these groups are more for
119 administrative purposes than control. The project is directed by the
120 community of developers and users, which anyone can join. All you need
121 to do is subscribe to the mailing lists and participate in the
122 discussions. (See the Developer's FAQ for information on how to get
123 involved in PostgreSQL development.)
125 1.3) What is the copyright of PostgreSQL?
127 PostgreSQL is distributed under the classic BSD license. Basically, it
128 allows users to do anything they want with the code, including
129 reselling binaries without the source code. The only restriction is
130 that you not hold us legally liable for problems with the software.
131 There is also the requirement that this copyright appear in all copies
132 of the software. Here is the actual BSD license we use:
134 PostgreSQL Data Base Management System
136 Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
137 Portions Copyright (c) 1994-1996 Regents of the University of
140 Permission to use, copy, modify, and distribute this software and its
141 documentation for any purpose, without fee, and without a written
142 agreement is hereby granted, provided that the above copyright notice
143 and this paragraph and the following two paragraphs appear in all
146 IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY
147 FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES,
148 INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND
149 ITS DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN
150 ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
152 THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
153 INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF
154 MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE
155 PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND THE UNIVERSITY OF
156 CALIFORNIA HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT,
157 UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
159 1.4) What platforms does PostgreSQL support?
161 In general, any modern Unix-compatible platform should be able to run
162 PostgreSQL. The platforms that had received explicit testing at the
163 time of release are listed in the installation instructions.
165 PostgreSQL also runs natively on Microsoft Windows NT-based operating
166 systems like Win2000 SP4, WinXP, and Win2003. A prepackaged installer
167 is available at http://www.postgresql.org/download/windows.
168 MSDOS-based versions of Windows (Win95, Win98, WinMe) can run
169 PostgreSQL using Cygwin.
171 There is also a Novell Netware 6 port at
172 http://developer.novell.com/wiki/index.php/Postgresql, and an OS/2
173 (eComStation) version at
174 http://hobbes.nmsu.edu/cgi-bin/h-search?sh=1&button=Search&key=postgre
175 SQL&stype=all&sort=type&dir=%2F.
177 1.5) Where can I get PostgreSQL?
179 Via web browser, use http://www.postgresql.org/ftp/, and via ftp, use
180 ftp://ftp.postgresql.org/pub/.
182 1.6) What is the most recent release?
184 The latest release of PostgreSQL is version 8.3.3.
186 We plan to have a major release every year, with minor releases every
189 1.7) Where can I get support?
191 The PostgreSQL community provides assistance to many of its users via
192 email. The main web site to subscribe to the email lists is
193 http://www.postgresql.org/community/lists/. The general or bugs lists
194 are a good place to start.
196 The major IRC channel is #postgresql on Freenode (irc.freenode.net).
197 To connect you can use the Unix program irc -c '#postgresql' "$USER"
198 irc.freenode.net or use any other IRC clients. A Spanish one also
199 exists on the same network, (#postgresql-es), a French one,
200 (#postgresqlfr), and a Brazilian one, (#postgresql-br). There is also
201 a PostgreSQL channel on EFNet.
203 A list of commercial support companies is available at
204 http://www.postgresql.org/support/professional_support.
206 1.8) How do I submit a bug report?
208 Visit the PostgreSQL bug form at
209 http://www.postgresql.org/support/submitbug. Also check out our ftp
210 site ftp://ftp.postgresql.org/pub/ to see if there is a more recent
213 Bugs submitted using the bug form or posted to any PostgreSQL mailing
214 list typically generates one of the following replies:
215 * It is not a bug, and why
216 * It is a known bug and is already on the TODO list
217 * The bug has been fixed in the current release
218 * The bug has been fixed but is not packaged yet in an official
220 * A request is made for more detailed information:
223 + Reproducible test case
224 + Debugging information
225 + Debugger backtrace output
226 * The bug is new. The following might happen:
227 + A patch is created and will be included in the next major or
229 + The bug cannot be fixed immediately and is added to the TODO
232 1.9) How do I find out about known bugs or missing features?
234 PostgreSQL supports an extended subset of SQL:2003. See our TODO list
235 for known bugs, missing features, and future plans.
237 A feature request usually results in one of the following replies:
238 * The feature is already on the TODO list
239 * The feature is not desired because:
240 + It duplicates existing functionality that already follows the
242 + The feature would increase code complexity but add little
244 + The feature would be insecure or unreliable
245 * The new feature is added to the TODO list
247 PostgreSQL does not use a bug tracking system because we find it more
248 efficient to respond directly to email and keep the TODO list
249 up-to-date. In practice, bugs don't last very long in the software,
250 and bugs that affect a large number of users are fixed rapidly. The
251 only place to find all changes, improvements, and fixes in a
252 PostgreSQL release is to read the CVS log messages. Even the release
253 notes do not list every change made to the software.
255 1.10) What documentation is available?
257 PostgreSQL includes extensive documentation, including a large manual,
258 manual pages, and some test examples. See the /doc directory. You can
259 also browse the manuals online at http://www.postgresql.org/docs.
261 There are two PostgreSQL books available online at
262 http://www.postgresql.org/docs/books/awbook.html and
263 http://www.commandprompt.com/ppbook/. There are a number of PostgreSQL
264 books available for purchase. One of the most popular ones is by Korry
265 Douglas. A list of book reviews can be found at
266 http://www.postgresql.org/docs/books/. There is also a collection of
267 PostgreSQL technical articles at
268 http://wiki.postgresql.org/wiki/Community_Generated_Articles%2C_Guides
269 %2C_and_Documentation.
271 The command line client program psql has some \d commands to show
272 information about types, operators, functions, aggregates, etc. - use
273 \? to display the available commands.
275 Our web site contains even more documentation.
277 1.11) How can I learn SQL?
279 First, consider the PostgreSQL-specific books mentioned above. Many of
280 our users also like The Practical SQL Handbook, Bowman, Judith S., et
281 al., Addison-Wesley. Others like The Complete Reference SQL, Groff et
284 There are also many nice tutorials available online:
285 * http://www.intermedia.net/support/sql/sqltut.shtm
286 * http://sqlcourse.com
287 * http://www.w3schools.com/sql/default.asp
288 * http://mysite.verizon.net/Graeme_Birchall/id1.html
291 1.12) How do I submit a patch or join the development team?
293 See the Developer's FAQ.
295 1.13) How does PostgreSQL compare to other DBMSs? Can PostgreSQL be embedded?
297 There are several ways of measuring software: features, performance,
298 reliability, support, and price.
301 PostgreSQL has most features present in large commercial DBMSs,
302 like transactions, subselects, triggers, views, foreign key
303 referential integrity, and sophisticated locking. We have some
304 features they do not have, like user-defined types,
305 inheritance, rules, and multi-version concurrency control to
306 reduce lock contention.
309 PostgreSQL's performance is comparable to other commercial and
310 open source databases. It is faster for some things, slower for
311 others. Our performance is usually +/-10% compared to other
315 We realize that a DBMS must be reliable, or it is worthless. We
316 strive to release well-tested, stable code that has a minimum
317 of bugs. Each release has at least one month of beta testing,
318 and our release history shows that we can provide stable, solid
319 releases that are ready for production use. We believe we
320 compare favorably to other database software in this area.
323 Our mailing lists provide contact with a large group of
324 developers and users to help resolve any problems encountered.
325 While we cannot guarantee a fix, commercial DBMSs do not always
326 supply a fix either. Direct access to developers, the user
327 community, manuals, and the source code often make PostgreSQL
328 support superior to other DBMSs. There is commercial
329 per-incident support available for those who need it. (See FAQ
333 We are free for all use, both commercial and non-commercial.
334 You can add our code to your product with no limitations,
335 except those outlined in our BSD-style license stated above.
337 PostgreSQL is designed as a client/server architecture, which requires
338 separate processes for each client and server, and various helper
339 processes. Many embedded architectures can support such requirements.
340 However, if your embedded architecture requires the database server to
341 run inside the application process, you cannot use Postgres and should
342 select a lighter-weight database solution.
344 1.14) Will PostgreSQL handle recent daylight saving time changes in various
347 USA daylight saving time changes are included in PostgreSQL release
348 8.0.[4+], and all later major releases, e.g. 8.1. Canada and Western
349 Australia changes are included in 8.0.[10+], 8.1.[6+], and all later
350 major releases. PostgreSQL releases prior to 8.0 use the operating
351 system's timezone database for daylight saving information.
353 1.15) How do I unsubscribe from the PostgreSQL email lists? How do I avoid
354 receiving duplicate emails?
356 The PostgreSQL Majordomo page allows subscribing or unsubscribing from
357 any of the PostgreSQL email lists. (You might need to have your
358 Majordomo password emailed to you to log in.)
360 All PostgreSQL email lists are configured so a group reply goes to the
361 email list and the original email author. This is done so users
362 receive the quickest possible email replies. If you would prefer not
363 to receive duplicate email from the list in cases where you already
364 receive an email directly, check eliminatecc from the Majordomo Change
365 Settings page. You can also prevent yourself from receiving copies of
366 emails you post to the lists by unchecking selfcopy.
367 _________________________________________________________________
369 User Client Questions
371 2.1) What interfaces are available for PostgreSQL?
373 The PostgreSQL install includes only the C and embedded C interfaces.
374 All other interfaces are independent projects that are downloaded
375 separately; being separate allows them to have their own release
376 schedule and development teams.
378 Some programming languages like PHP include an interface to
379 PostgreSQL. Interfaces for languages like Perl, TCL, Python, and many
380 others are available at http://pgfoundry.org.
382 2.2) What tools are available for using PostgreSQL with Web pages?
384 A nice introduction to Database-backed Web pages can be seen at:
385 http://www.webreview.com
387 For Web integration, PHP (http://www.php.net) is an excellent
390 For complex cases, many use the Perl and DBD::Pg with CGI.pm or
393 2.3) Does PostgreSQL have a graphical user interface?
395 There are a large number of GUI Tools that are available for
396 PostgreSQL from both commercial and open source developers. A detailed
397 list can be found in the Community Guide to PostgreSQL GUI Tools.
398 _________________________________________________________________
400 Administrative Questions
402 3.1) How do I install PostgreSQL somewhere other than /usr/local/pgsql?
404 Specify the --prefix option when running configure.
406 3.2) How do I control connections from other hosts?
408 By default, PostgreSQL only allows connections from the local machine
409 using Unix domain sockets or TCP/IP connections. Other machines will
410 not be able to connect unless you modify listen_addresses in the
411 postgresql.conf file, enable host-based authentication by modifying
412 the $PGDATA/pg_hba.conf file, and restart the database server.
414 3.3) How do I tune the database engine for better performance?
416 There are three major areas for potential performance improvement:
419 This involves modifying queries to obtain better performance:
421 + Creation of indexes, including expression and partial indexes
422 + Use of COPY instead of multiple INSERTs
423 + Grouping of multiple statements into a single transaction to
424 reduce commit overhead
425 + Use of CLUSTER when retrieving many rows from an index
426 + Use of LIMIT for returning a subset of a query's output
427 + Use of Prepared queries
428 + Use of ANALYZE to maintain accurate optimizer statistics
429 + Regular use of VACUUM or pg_autovacuum
430 + Dropping of indexes during large data changes
433 A number of postgresql.conf settings affect performance. For
434 more details, see Administration Guide/Server Run-time
435 Environment/Run-time Configuration for a full listing, and for
437 http://www.varlena.com/varlena/GeneralBits/Tidbits/annotated_co
439 http://www.varlena.com/varlena/GeneralBits/Tidbits/perf.html.
442 The effect of hardware on performance is detailed in
443 http://www.powerpostgresql.com/PerfList/ and
444 http://momjian.us/main/writings/pgsql/hw_performance/index.html
447 3.4) What debugging features are available?
449 There are many log_* server configuration variables at
450 http://www.postgresql.org/docs/current/interactive/runtime-config-logg
451 ing.html that enable printing of query and process statistics which
452 can be very useful for debugging and performance measurements.
454 3.5) Why do I get "Sorry, too many clients" when trying to connect?
456 You have reached the default limit of 100 database sessions. You need
457 to increase the server's limit on how many concurrent backend
458 processes it can start by changing the max_connections value in
459 postgresql.conf and restarting the server.
461 3.6) What is the upgrade process for PostgreSQL?
463 See http://www.postgresql.org/support/versioning for a general
464 discussion about upgrading, and
465 http://www.postgresql.org/docs/current/static/install-upgrading.html
466 for specific instructions.
468 3.7) What computer hardware should I use?
470 Because PC hardware is mostly compatible, people tend to believe that
471 all PC hardware is of equal quality. It is not. ECC RAM, SCSI, and
472 quality motherboards are more reliable and have better performance
473 than less expensive hardware. PostgreSQL will run on almost any
474 hardware, but if reliability and performance are important it is wise
475 to research your hardware options thoroughly. A disk controller with a
476 battery-backed cache is also useful. Our email lists can be used to
477 discuss hardware options and tradeoffs.
478 _________________________________________________________________
480 Operational Questions
482 4.1) How do I SELECT only the first few rows of a query? A random row?
484 To retrieve only a few rows, if you know at the number of rows needed
485 at the time of the SELECT use LIMIT . If an index matches the ORDER BY
486 it is possible the entire query does not have to be executed. If you
487 don't know the number of rows at SELECT time, use a cursor and FETCH.
489 To SELECT a random row, use:
495 4.2) How do I find out what tables, indexes, databases, and users are
496 defined? How do I see the queries used by psql to display them?
498 Use the \dt command to see tables in psql. For a complete list of
499 commands inside psql you can use \?. Alternatively you can read the
500 source code for psql in file pgsql/src/bin/psql/describe.c, it
501 contains SQL commands that generate the output for psql's backslash
502 commands. You can also start psql with the -E option so it will print
503 out the queries it uses to execute the commands you give. PostgreSQL
504 also provides an SQL compliant INFORMATION SCHEMA interface you can
505 query to get information about the database.
507 There are also system tables beginning with pg_ that describe these
510 Use psql -l will list all databases.
512 Also try the file pgsql/src/tutorial/syscat.source. It illustrates
513 many of the SELECTs needed to get information from the database system
516 4.3) How do you change a column's data type?
518 Changing the data type of a column can be done easily in 8.0 and later
519 with ALTER TABLE ALTER COLUMN TYPE.
521 In earlier releases, do this:
523 ALTER TABLE tab ADD COLUMN new_col new_data_type;
524 UPDATE tab SET new_col = CAST(old_col AS new_data_type);
525 ALTER TABLE tab DROP COLUMN old_col;
528 You might then want to do VACUUM FULL tab to reclaim the disk space
529 used by the expired rows.
531 4.4) What is the maximum size for a row, a table, and a database?
533 These are the limits:
535 Maximum size for a database? unlimited (32 TB databases exist)
536 Maximum size for a table? 32 TB
537 Maximum size for a row? 400 GB
538 Maximum size for a field? 1 GB
539 Maximum number of rows in a table? unlimited
540 Maximum number of columns in a table? 250-1600 depending on column
542 Maximum number of indexes on a table? unlimited
544 Of course, these are not actually unlimited, but limited to available
545 disk space and memory/swap space. Performance may suffer when these
546 values get unusually large.
548 The maximum table size of 32 TB does not require large file support
549 from the operating system. Large tables are stored as multiple 1 GB
550 files so file system size limits are not important.
552 The maximum table size, row size, and maximum number of columns can be
553 quadrupled by increasing the default block size to 32k. The maximum
554 table size can also be increased using table partitioning.
556 One limitation is that indexes can not be created on columns longer
557 than about 2,000 characters. Fortunately, such indexes are rarely
558 needed. Uniqueness is best guaranteed by a function index of an MD5
559 hash of the long column, and full text indexing allows for searching
560 of words within the column.
562 4.5) How much database disk space is required to store data from a typical
565 A PostgreSQL database may require up to five times the disk space to
566 store data from a text file.
568 As an example, consider a file of 100,000 lines with an integer and
569 text description on each line. Suppose the text string avergages
570 twenty bytes in length. The flat file would be 2.8 MB. The size of the
571 PostgreSQL database file containing this data can be estimated as 5.2
573 24 bytes: each row header (approximate)
574 24 bytes: one int field and one text field
575 + 4 bytes: pointer on page to tuple
576 ----------------------------------------
579 The data page size in PostgreSQL is 8192 bytes (8 KB), so:
582 ------------------- = 158 rows per database page (rounded down)
586 -------------------- = 633 database pages (rounded up)
589 633 database pages * 8192 bytes per page = 5,185,536 bytes (5.2 MB)
591 Indexes do not require as much overhead, but do contain the data that
592 is being indexed, so they can be large also.
594 NULLs are stored as bitmaps, so they use very little space.
596 4.6) Why are my queries slow? Why don't they use my indexes?
598 Indexes are not used by every query. Indexes are used only if the
599 table is larger than a minimum size, and the query selects only a
600 small percentage of the rows in the table. This is because the random
601 disk access caused by an index scan can be slower than a straight read
602 through the table, or sequential scan.
604 To determine if an index should be used, PostgreSQL must have
605 statistics about the table. These statistics are collected using
606 VACUUM ANALYZE, or simply ANALYZE. Using statistics, the optimizer
607 knows how many rows are in the table, and can better determine if
608 indexes should be used. Statistics are also valuable in determining
609 optimal join order and join methods. Statistics collection should be
610 performed periodically as the contents of the table change.
612 Indexes are normally not used for ORDER BY or to perform joins. A
613 sequential scan followed by an explicit sort is usually faster than an
614 index scan of a large table. However, LIMIT combined with ORDER BY
615 often will use an index because only a small portion of the table is
618 If you believe the optimizer is incorrect in choosing a sequential
619 scan, use SET enable_seqscan TO 'off' and run query again to see if an
620 index scan is indeed faster.
622 When using wild-card operators such as LIKE or ~, indexes can only be
623 used in certain circumstances:
624 * The beginning of the search string must be anchored to the start
626 + LIKE patterns must not start with %.
627 + ~ (regular expression) patterns must start with ^.
628 * The search string can not start with a character class, e.g.
630 * Case-insensitive searches such as ILIKE and ~* do not utilize
631 indexes. Instead, use expression indexes, which are described in
633 * The default C locale must be used during initdb because it is not
634 possible to know the next-greatest character in a non-C locale.
635 You can create a special text_pattern_ops index for such cases
636 that work only for LIKE indexing. It is also possible to use full
637 text indexing for word searches.
639 4.7) How do I see how the query optimizer is evaluating my query?
641 See the EXPLAIN manual page.
643 4.8) How do I perform regular expression searches and case-insensitive
644 regular expression searches? How do I use an index for case-insensitive
647 The ~ operator does regular expression matching, and ~* does
648 case-insensitive regular expression matching. The case-insensitive
649 variant of LIKE is called ILIKE.
651 Case-insensitive equality comparisons are normally expressed as:
654 WHERE lower(col) = 'abc';
656 This will not use an standard index. However, if you create an
657 expression index, it will be used:
658 CREATE INDEX tabindex ON tab (lower(col));
660 If the above index is created as UNIQUE, though the column can store
661 upper and lowercase characters, it can not have identical values that
662 differ only in case. To force a particular case to be stored in the
663 column, use a CHECK constraint or a trigger.
665 4.9) In a query, how do I detect if a field is NULL? How do I concatenate
666 possible NULLs? How can I sort on whether a field is NULL or not?
668 You test the column with IS NULL and IS NOT NULL, like this:
673 To concatentate with possible NULLs, use COALESCE(), like this:
674 SELECT COALESCE(col1, '') || COALESCE(col2, '')
677 To sort by the NULL status, use the IS NULL and IS NOT NULL modifiers
678 in your ORDER BY clause. Things that are true will sort higher than
679 things that are false, so the following will put NULL entries at the
680 top of the resulting list:
683 ORDER BY (col IS NOT NULL)
685 4.10) What is the difference between the various character types?
687 Type Internal Name Notes
688 VARCHAR(n) varchar size specifies maximum length, no padding
689 CHAR(n) bpchar blank padded to the specified fixed length
690 TEXT text no specific upper limit on length
691 BYTEA bytea variable-length byte array (null-byte safe)
692 "char" char one character
694 You will see the internal name when examining system catalogs and in
697 The first four types above are "varlena" types (i.e., the first four
698 bytes on disk are the length, followed by the data). Thus the actual
699 space used is slightly greater than the declared size. However, long
700 values are also subject to compression, so the space on disk might
701 also be less than expected.
702 VARCHAR(n) is best when storing variable-length strings and it limits
703 how long a string can be. TEXT is for strings of unlimited length,
704 with a maximum of one gigabyte.
706 CHAR(n) is for storing strings that are all the same length. CHAR(n)
707 pads with blanks to the specified length, while VARCHAR(n) only stores
708 the characters supplied. BYTEA is for storing binary data,
709 particularly values that include NULL bytes. All the types described
710 here have similar performance characteristics.
712 4.11.1) How do I create a serial/auto-incrementing field?
714 PostgreSQL supports a SERIAL data type. It auto-creates a sequence.
716 CREATE TABLE person (
721 is automatically translated into this:
722 CREATE SEQUENCE person_id_seq;
723 CREATE TABLE person (
724 id INT4 NOT NULL DEFAULT nextval('person_id_seq'),
728 Automatically created sequence are named <table>_<serialcolumn>_seq,
729 where table and serialcolumn are the names of the table and SERIAL
730 column, respectively. See the create_sequence manual page for more
731 information about sequences.
733 4.11.2) How do I get the value of a SERIAL insert?
735 The simplest way is to retrieve the assigned SERIAL value with
736 RETURNING. Using the example table in 4.11.1, it would look like this:
737 INSERT INTO person (name) VALUES ('Blaise Pascal') RETURNING id;
739 You can also call nextval() and use that value in the INSERT, or call
740 currval() after the INSERT.
742 4.11.3) Doesn't currval() lead to a race condition with other users?
744 No. currval() returns the current value assigned by your session, not
747 4.11.4) Why aren't my sequence numbers reused on transaction abort? Why are
748 there gaps in the numbering of my sequence/SERIAL column?
750 To improve concurrency, sequence values are given out to running
751 transactions as needed and are not locked until the transaction
752 completes. This causes gaps in numbering from aborted transactions.
754 4.12) What is an OID? What is a CTID?
756 If a table is created WITH OIDS, each row gets a unique a OID. OIDs
757 are automatically assigned unique 4-byte integers that are unique
758 across the entire installation. However, they overflow at 4 billion,
759 and then the OIDs start being duplicated. PostgreSQL uses OIDs to link
760 its internal system tables together.
762 To uniquely number rows in user tables, it is best to use SERIAL
763 rather than OIDs because SERIAL sequences are unique only within a
764 single table. and are therefore less likely to overflow. SERIAL8 is
765 available for storing eight-byte sequence values.
767 CTIDs are used to identify specific physical rows with block and
768 offset values. CTIDs change after rows are modified or reloaded. They
769 are used by index entries to point to physical rows.
771 4.13) Why do I get the error "ERROR: Memory exhausted in AllocSetAlloc()"?
773 You probably have run out of virtual memory on your system, or your
774 kernel has a low limit for certain resources. Try this before starting
779 Depending on your shell, only one of these may succeed, but it will
780 set your process data segment limit much higher and perhaps allow the
781 query to complete. This command applies to the current process, and
782 all subprocesses created after the command is run. If you are having a
783 problem with the SQL client because the backend is returning too much
784 data, try it before starting the client.
786 4.14) How do I tell what PostgreSQL version I am running?
788 From psql, type SELECT version();
790 4.15) How do I create a column that will default to the current time?
792 Use CURRENT_TIMESTAMP:
793 CREATE TABLE test (x int, modtime TIMESTAMP DEFAULT CURRENT_TIMESTAMP );
795 4.16) How do I perform an outer join?
797 PostgreSQL supports outer joins using the SQL standard syntax. Here
800 FROM t1 LEFT OUTER JOIN t2 ON (t1.col = t2.col);
804 FROM t1 LEFT OUTER JOIN t2 USING (col);
806 These identical queries join t1.col to t2.col, and also return any
807 unjoined rows in t1 (those with no match in t2). A RIGHT join would
808 add unjoined rows of t2. A FULL join would return the matched rows
809 plus all unjoined rows from t1 and t2. The word OUTER is optional and
810 is assumed in LEFT, RIGHT, and FULL joins. Ordinary joins are called
813 4.17) How do I perform queries using multiple databases?
815 There is no way to query a database other than the current one.
816 Because PostgreSQL loads database-specific system catalogs, it is
817 uncertain how a cross-database query should even behave.
819 contrib/dblink allows cross-database queries using function calls. Of
820 course, a client can also make simultaneous connections to different
821 databases and merge the results on the client side.
823 4.18) How do I return multiple rows or columns from a function?
825 It is easy using set-returning functions,
826 http://wiki.postgresql.org/wiki/Return_more_than_one_row_of_data_from_
829 4.19) Why do I get "relation with OID ##### does not exist" errors when
830 accessing temporary tables in PL/PgSQL functions?
832 In PostgreSQL versions < 8.3, PL/PgSQL caches function scripts, and an
833 unfortunate side effect is that if a PL/PgSQL function accesses a
834 temporary table, and that table is later dropped and recreated, and
835 the function called again, the function will fail because the cached
836 function contents still point to the old temporary table. The solution
837 is to use EXECUTE for temporary table access in PL/PgSQL. This will
838 cause the query to be reparsed every time.
840 This problem does not occur in PostgreSQL 8.3 and later.
842 4.20) What replication solutions are available?
844 Though "replication" is a single term, there are several technologies
845 for doing replication, with advantages and disadvantages for each.
847 Master/slave replication allows a single master to receive read/write
848 queries, while slaves can only accept read/SELECT queries. The most
849 popular freely available master-slave PostgreSQL replication solution
852 Multi-master replication allows read/write queries to be sent to
853 multiple replicated computers. This capability also has a severe
854 impact on performance due to the need to synchronize changes between
855 servers. PGCluster is the most popular such solution freely available
858 There are also commercial and hardware-based replication solutions
859 available supporting a variety of replication models.
861 4.21) Why are my table and column names not recognized in my query? Why is
862 capitalization not preserved?
864 The most common cause of unrecognized names is the use of
865 double-quotes around table or column names during table creation. When
866 double-quotes are used, table and column names (called identifiers)
867 are stored case-sensitive, meaning you must use double-quotes when
868 referencing the names in a query. Some interfaces, like pgAdmin,
869 automatically double-quote identifiers during table creation. So, for
870 identifiers to be recognized, you must either:
871 * Avoid double-quoting identifiers when creating tables
872 * Use only lowercase characters in identifiers
873 * Double-quote identifiers when referencing them in queries