summaryrefslogtreecommitdiff
path: root/doc/src/FAQ/FAQ.html
blob: 1a97dcffe9fcf757753a93fb78af2d1fb1a69d44 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
<!DOCTYPE html PUBLIC "-//W3C//DTD html 4.01 transitional//EN">

<HTML>
  <!-- DOCTYPE html PUBLIC "-//W3C//DTD HTML 3.2//EN" -->
  <!-- HTML -->

  <HEAD>
    <META name="generator" content="HTML Tidy, see www.w3.org">

    <TITLE>PostgreSQL FAQ</TITLE>
  </HEAD>

  <BODY bgcolor="#ffffff" text="#000000" link="#ff0000" vlink="#a00000" alink="#0000ff">
    <H1>Frequently Asked Questions (FAQ) for PostgreSQL</H1>

    <P>Last updated: Thu Jan 10 18:33:31 EST 2002</P>

    <P>Current maintainer: Bruce Momjian (<A href="mailto:pgman@candle.pha.pa.us">pgman@candle.pha.pa.us</A>)<BR>
    </P>

    <P>The most recent version of this document can be viewed at <A href="http://www.Postgresql.org/docs/faq-english.html">http://www.PostgreSQL.org/docs/faq-english.html</A>.</P>

    <P>Platform-specific questions are answered at <A href="http://www.PostgreSQL.org/users-lounge/docs/faq.html">http://www.PostgreSQL.org/users-lounge/docs/faq.html</A>.</P>
    <HR>

    <H2 align="center">General Questions</H2>
    <A href="#1.1">1.1</A>) What is PostgreSQL? How is it pronounced?<BR>
     <A href="#1.2">1.2</A>) What is the copyright on PostgreSQL?<BR>
     <A href="#1.3">1.3</A>) What Unix platforms does PostgreSQL run on?<BR>
     <A href="#1.4">1.4</A>) What non-Unix ports are available?<BR>
     <A href="#1.5">1.5</A>) Where can I get PostgreSQL?<BR>
     <A href="#1.6">1.6</A>) Where can I get support?<BR>
     <A href="#1.7">1.7</A>) What is the latest release?<BR>
     <A href="#1.8">1.8</A>) What documentation is available?<BR>
     <A href="#1.9">1.9</A>) How do I find out about known bugs or missing features?<BR>
     <A href="#1.10">1.10</A>) How can I learn <SMALL>SQL</SMALL>?<BR>
     <A href="#1.11">1.11</A>) Is PostgreSQL Y2K compliant?<BR>
     <A href="#1.12">1.12</A>) How do I join the development team?<BR>
     <A href="#1.13">1.13</A>) How do I submit a bug report?<BR>
     <A href="#1.14">1.14</A>) How does PostgreSQL compare to other <SMALL>DBMS</SMALL>s?<BR>
     <A href="#1.15">1.15</A>) How can I financially assist PostgreSQL?<BR>
     

    <H2 align="center">User Client Questions</H2>
    <A href="#2.1">2.1</A>) Are there <SMALL>ODBC</SMALL> drivers for PostgreSQL?<BR>
     <A href="#2.2">2.2</A>) What tools are available for using PostgreSQL with Web pages?<BR>
     <A href="#2.3">2.3</A>) Does PostgreSQL have a graphical user interface? A report generator? An embedded query language interface?<BR>
     <A href="#2.4">2.4</A>) What languages are available to communicate with PostgreSQL?<BR>
     

    <H2 align="center">Administrative Questions</H2>
    <A href="#3.1">3.1</A>) How do I install PostgreSQL somewhere other than <I>/usr/local/pgsql</I>?<BR>
     <A href="#3.2">3.2</A>) When I start <I>postmaster</I>, I get a <I>Bad System Call</I> or core dumped message. Why?<BR>
     <A href="#3.3">3.3</A>) When I try to start <I>postmaster</I>, I get <I>IpcMemoryCreate</I> errors. Why?<BR>
     <A href="#3.4">3.4</A>) When I try to start <I>postmaster</I>, I get <I>IpcSemaphoreCreate</I> errors. Why?<BR>
     <A href="#3.5">3.5</A>) How do I prevent other hosts from accessing my PostgreSQL database?<BR>
     <A href="#3.6">3.6</A>) Why can't I connect to my database from another machine?<BR>
     <A href="#3.7">3.7</A>) How do I tune the database engine for better performance?<BR>
     <A href="#3.8">3.8</A>) What debugging features are available?<BR>
     <A href="#3.9">3.9</A>) Why do I get <I>"Sorry, too many clients"</I> when trying to connect?<BR>
     <A href="#3.10">3.10</A>) What are the <I>pg_sorttempNNN.NN</I> files in my database directory?<BR>
     

    <H2 align="center">Operational Questions</H2>
    <A href="#4.1">4.1</A>) What is the difference between binary cursors and normal cursors?<BR>
     <A href="#4.2">4.2</A>) How do I <SMALL>SELECT</SMALL> only the first few rows of a query?<BR>
     <A href="#4.3">4.3</A>) How do I get a list of tables or other things I can see in <I>psql</I>?<BR>
     <A href="#4.4">4.4</A>) How do you remove a column from a table?<BR>
     <A href="#4.5">4.5</A>) What is the maximum size for a row, a table, and a database?<BR>
     <A href="#4.6">4.6</A>) How much database disk space is required to store data from a typical text file?<BR>
     <A href="#4.7">4.7</A>) How do I find out what tables or indexes are defined in the database?<BR>
     <A href="#4.8">4.8</A>) My queries are slow or don't make use of the indexes. Why?<BR>
     <A href="#4.9">4.9</A>) How do I see how the query optimizer is evaluating my query?<BR>
     <A href="#4.10">4.10</A>) What is an R-tree index?<BR>
     <A href="#4.11">4.11</A>) What is the Genetic Query Optimizer?<BR>
     <A href="#4.12">4.12</A>) How do I perform regular expression searches and case-insensitive regular expression searches? How do I use an index for case-insensitive searches?<BR>
     <A href="#4.13">4.13</A>) In a query, how do I detect if a field is <SMALL>NULL</SMALL>?<BR>
     <A href="#4.14">4.14</A>) What is the difference between the various character types?<BR>
     <A href="#4.15.1">4.15.1</A>) How do I create a serial/auto-incrementing field?<BR>
     <A href="#4.15.2">4.15.2</A>) How do I get the value of a <SMALL>SERIAL</SMALL> insert?<BR>
     <A href="#4.15.3">4.15.3</A>) Don't <I>currval()</I> and <I>nextval()</I> lead to a race condition with other users?<BR>
     <A href="#4.16">4.16</A>) What is an <SMALL>OID</SMALL>? What is a <SMALL>TID</SMALL>?<BR>
     <A href="#4.17">4.17</A>) What is the meaning of some of the terms used in PostgreSQL?<BR>
     <A href="#4.18">4.18</A>) Why do I get the error <I>"ERROR: Memory exhausted in AllocSetAlloc()"</I>?<BR>
     <A href="#4.19">4.19</A>) How do I tell what PostgreSQL version I am running?<BR>
     <A href="#4.20">4.20</A>) Why does my large-object operations get <I>"invalid large obj descriptor"</I>?<BR>
     <A href="#4.21">4.21</A>) How do I create a column that will default to the current time?<BR>
     <A href="#4.22">4.22</A>) Why are my subqueries using <CODE><SMALL>IN</SMALL></CODE> so slow?<BR>
     <A href="#4.23">4.23</A>) How do I perform an outer join?<BR>
     <A href="#4.24">4.24</A>) How do I perform queries using multiple databases?<BR>
     

    <H2 align="center">Extending PostgreSQL</H2>
    <A href="#5.1">5.1</A>) I wrote a user-defined function. When I run it in <I>psql</I>, why does it dump core?<BR>
     <A href="#5.2">5.2</A>) How can I contribute some nifty new types and functions to PostgreSQL?<BR>
     <A href="#5.3">5.3</A>) How do I write a C function to return a tuple?<BR>
     <A href="#5.4">5.4</A>) I have changed a source file. Why does the recompile not see the change?<BR>
     
    <HR>

    <H2 align="center">General Questions</H2>

    <H4><A name="1.1">1.1</A>) What is PostgreSQL?</H4>

    <P>PostgreSQL is pronounced <I>Post-Gres-Q-L</I>.</P>

    <P>PostgreSQL is an enhancement of the POSTGRES database management system, a next-generation <SMALL>DBMS</SMALL> research prototype. While PostgreSQL retains the powerful data model and rich data types of POSTGRES, it replaces the PostQuel query language with an extended subset of <SMALL>SQL</SMALL>. PostgreSQL is free and the complete source is available.</P>

    <P>PostgreSQL development is performed by a team of Internet developers who all subscribe to the PostgreSQL development mailing list. The current coordinator is Marc G. Fournier (<A href="mailto:scrappy@PostgreSQL.org">scrappy@PostgreSQL.org</A>). (See below on how to join). This team is now responsible for all development of PostgreSQL.</P>

    <P>The authors of PostgreSQL 1.01 were Andrew Yu and Jolly Chen. Many others have contributed to the porting, testing, debugging, and enhancement of the code. The original Postgres code, from which PostgreSQL is derived, was the effort of many graduate students, undergraduate students, and staff programmers working under the direction of Professor Michael Stonebraker at the University of California, Berkeley.</P>

    <P>The original name of the software at Berkeley was Postgres. When <SMALL>SQL</SMALL> functionality was added in 1995, its name was changed to Postgres95. The name was changed at the end of 1996 to PostgreSQL.</P>

    <H4><A name="1.2">1.2</A>) What is the copyright on PostgreSQL?</H4>

    <P>PostgreSQL is subject to the following COPYRIGHT:</P>

    <P>PostgreSQL Data Base Management System</P>

    <P>Portions copyright (c) 1996-2002, PostgreSQL Global Development Group Portions Copyright (c) 1994-6 Regents of the University of California</P>

    <P>Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies.</P>

    <P>IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.</P>

    <P>THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.</P>

    <H4><A name="1.3">1.3</A>) What Unix platforms does PostgreSQL run on?</H4>

    <P>In general, a modern Unix-compatible platform should be able to run PostgreSQL. The platforms that had received explicit testing at the time of release are listed in the installation instructions.</P>

    <H4><A name="1.4">1.4</A>) What non-Unix ports are available?</H4>

    <P><STRONG>Client</STRONG></P>

    <P>It is possible to compile the <I>libpq</I> C library, psql, and other interfaces and binaries to run on MS Windows platforms. In this case, the client is running on MS Windows, and communicates via TCP/IP to a server running on one of our supported Unix platforms. A file <I>win31.mak</I> is included in the distribution for making a Win32 <I>libpq</I> library and <I>psql</I>. PostgreSQL also communicates with <SMALL>ODBC</SMALL> clients.</P>

    <P><STRONG>Server</STRONG></P>

    <P>The database server can run on Windows NT and Win2k using Cygwin, the Cygnus Unix/NT porting library. See <I>pgsql/doc/FAQ_MSWIN</I> in the distribution or the <A href="http://www.postgresql.org/docs/faq-mswin.html">MS Windows FAQ</A> on our web site. We have no plan to do a native port to any Microsoft platform.</P>

    <H4><A name="1.5">1.5</A>) Where can I get PostgreSQL?</H4>

    <P>The primary anonymous ftp site for PostgreSQL is <A href="ftp://ftp.PostgreSQL.org/pub">ftp://ftp.PostgreSQL.org/pub</A>. For mirror sites, see our main web site.</P>

    <H4><A name="1.6">1.6</A>) Where can I get support?</H4>

    <P>The main mailing list is: <A href="mailto:pgsql-general@PostgreSQL.org">pgsql-general@PostgreSQL.org</A>. It is available for discussion of matters pertaining to PostgreSQL. To subscribe, send mail with the following lines in the body (not the subject line):</P>
<PRE>
    subscribe
    end
</PRE>

    <P>to <A href="mailto:pgsql-general-request@PostgreSQL.org">pgsql-general-request@PostgreSQL.org</A>.</P>

    <P>There is also a digest list available. To subscribe to this list, send email to: <A href="mailto:pgsql-general-digest-request@PostgreSQL.org">pgsql-general-digest-request@PostgreSQL.org</A> with a body of:</P>
<PRE>
    subscribe
    end
</PRE>
    Digests are sent out to members of this list whenever the main list has received around 30k of messages. 

    <P>The bugs mailing list is available. To subscribe to this list, send email to <A href="mailto:pgsql-bugs-request@PostgreSQL.org">pgsql-bugs-request@PostgreSQL.org</A> with a body of:</P>
<PRE>
    subscribe
    end
</PRE>
    There is also a developers discussion mailing list available. To subscribe to this list, send email to <A href="mailto:pgsql-hackers-request@PostgreSQL.org">pgsql-hackers-request@PostgreSQL.org</A> with a body of: 
<PRE>
    subscribe
    end
</PRE>

    <P>Additional mailing lists and information about PostgreSQL can be found via the PostgreSQL WWW home page at:</P>

    <BLOCKQUOTE>
      <A href="http://www.PostgreSQL.org">http://www.PostgreSQL.org</A>
    </BLOCKQUOTE>

    <P>There is also an IRC channel on EFNet, channel <I>#PostgreSQL</I>. I use the Unix command <CODE>irc -c '#PostgreSQL' "$USER" irc.phoenix.net.</CODE></P>

    <P>A list of commercial support companies is available at <A href="http://www.postgresql.org/users-lounge/commercial-support.html">http://www.postgresql.org/users-lounge/commercial-support.html</A>.</P>

    <H4><A name="1.7">1.7</A>) What is the latest release?</H4>

    <P>The latest release of PostgreSQL is version 7.1.3.</P>

    <P>We plan to have major releases every four months.</P>

    <H4><A name="1.8">1.8</A>) What documentation is available?</H4>

    <P>Several manuals, manual pages, and some small test examples are included in the distribution. See the <I>/doc</I> directory. You can also browse the manual online at <A href="http://www.PostgreSQL.org/users-lounge/docs/">http://www.PostgreSQL.org/users-lounge/docs/</A>.</P>

    <P>There is a PostgreSQL book available at <A href="http://www.PostgreSQL.org/docs/awbook.html">http://www.PostgreSQL.org/docs/awbook.html</A>.</P>

    <P><I>psql</I> has some nice \d commands to show information about types, operators, functions, aggregates, etc.</P>

    <P>Our web site contains even more documentation.</P>

    <H4><A name="1.9">1.9</A>) How do I find out about known bugs or missing features?</H4>

    <P>PostgreSQL supports an extended subset of <SMALL>SQL</SMALL>-92. See our <A href="http://developer.PostgreSQL.org/todo.php">TODO</A> list for known bugs, missing features, and future plans.</P>

    <H4><A name="1.10">1.10</A>) How can I learn <SMALL>SQL</SMALL>?</H4>

    <P>The PostgreSQL book at <A href="http://www.PostgreSQL.org/docs/awbook.html">http://www.PostgreSQL.org/docs/awbook.html</A> teaches <SMALL>SQL</SMALL>. There is a nice tutorial at <A href="http://www.intermedia.net/support/sql/sqltut.shtm">http://www.intermedia.net/support/sql/sqltut.shtm</A> and at <A href="http://ourworld.compuserve.com/homepages/graeme_birchall/HTM_COOK.HTM">http://ourworld.compuserve.com/homepages/graeme_birchall/HTM_COOK.HTM.</A></P>

    <P>Another one is "Teach Yourself SQL in 21 Days, Second Edition" at <A href="http://members.tripod.com/er4ebus/sql/index.htm">http://members.tripod.com/er4ebus/sql/index.htm</A></P>

    <P>Many of our users like <I>The Practical SQL Handbook</I>, Bowman, Judith S., et al., Addison-Wesley. Others like <I>The Complete Reference SQL</I>, Groff et al., McGraw-Hill.</P>

    <H4><A name="1.11">1.11</A>) Is PostgreSQL Y2K compliant?</H4>

    <P>Yes, we easily handle dates past the year 2000 AD, and before 2000 BC.</P>

    <H4><A name="1.12">1.12</A>) How do I join the development team?</H4>

    <P>First, download the latest source and read the PostgreSQL Developers documentation on our web site, or in the distribution. Second, subscribe to the <I>pgsql-hackers</I> and <I>pgsql-patches</I> mailing lists. Third, submit high quality patches to pgsql-patches.</P>

    <P>There are about a dozen people who have commit privileges to the PostgreSQL <SMALL>CVS</SMALL> archive. They each have submitted so many high-quality patches that it was impossible for the existing committers to keep up, and we had confidence that patches they committed were of high quality.</P>

    <H4><A name="1.13">1.13</A>) How do I submit a bug report?</H4>

    <P>Please visit the <A href="http://www.postgresql.org/bugs/bugs.php">PostgreSQL BugTool</A> page, which gives guidelines and directions on how to submit a bug.</P>

    <P>Also check out our ftp site <A href="ftp://ftp.PostgreSQL.org/pub">ftp://ftp.PostgreSQL.org/pub</A> to see if there is a more recent PostgreSQL version or patches.</P>

    <H4><A name="1.14">1.14</A>) How does PostgreSQL compare to other <SMALL>DBMS</SMALL>s?</H4>

    <P>There are several ways of measuring software: features, performance, reliability, support, and price.</P>

    <DL>
      <DT><B>Features</B></DT>

      <DD>PostgreSQL has most features present in large commercial <SMALL>DBMS</SMALL>s, like transactions, subselects, triggers, views, foreign key referential integrity, and sophisticated locking. We have some features they do not have, like user-defined types, inheritance, rules, and multi-version concurrency control to reduce lock contention.<BR>
      <BR>
      </DD>

      <DT><B>Performance</B></DT>

      <DD>PostgreSQL runs in two modes. Normal <I>fsync</I> mode flushes every completed transaction to disk, guaranteeing that if the OS crashes or loses power in the next few seconds, all your data is safely stored on disk. In this mode, we are slower than most commercial databases, partly because few of them do such conservative flushing to disk in their default modes. In <I>no-fsync</I> mode, we are usually faster than commercial databases, though in this mode, an OS crash could cause data corruption. We are working to provide an intermediate mode that suffers less performance overhead than full fsync mode, and will allow data integrity within 30 seconds of an OS crash.<BR>
      <BR>
       In comparison to MySQL or leaner database systems, we are slower on inserts/updates because we have transaction overhead. Of course, MySQL does not have any of the features mentioned in the <I>Features</I> section above. We are built for flexibility and features, though we continue to improve performance through profiling and source code analysis. There is an interesting Web page comparing PostgreSQL to MySQL at <A href="http://openacs.org/why-not-mysql.html">http://openacs.org/why-not-mysql.html</A><BR>
      <BR>
       We handle each user connection by creating a Unix process. Backend processes share data buffers and locking information. With multiple CPUs, multiple backends can easily run on different CPUs.<BR>
      <BR>
      </DD>

      <DT><B>Reliability</B></DT>

      <DD>We realize that a <SMALL>DBMS</SMALL> must be reliable, or it is worthless. We strive to release well-tested, stable code that has a minimum of bugs. Each release has at least one month of beta testing, and our release history shows that we can provide stable, solid releases that are ready for production use. We believe we compare favorably to other database software in this area.<BR>
      <BR>
      </DD>

      <DT><B>Support</B></DT>

      <DD>Our mailing list provides a large group of developers and users to help resolve any problems encountered. While we can not guarantee a fix, commercial <SMALL>DBMS</SMALL>s do not always supply a fix either. Direct access to developers, the user community, manuals, and the source code often make PostgreSQL support superior to other <SMALL>DBMS</SMALL>s. There is commercial per-incident support available for those who need it. (See <A href="#1.6">support FAQ item</A>.)<BR>
      <BR>
      </DD>

      <DT><B>Price</B></DT>

      <DD>We are free for all use, both commercial and non-commercial. You can add our code to your product with no limitations, except those outlined in our BSD-style license stated above.<BR>
      <BR>
      </DD>
    </DL>

    <H4><A name="1.15">1.15</A>) How can I financially assist PostgreSQL?</H4>

    <P>PostgreSQL has had a first-class infrastructure since we started six years ago. This is all thanks to Marc Fournier, who has created and managed this infrastructure over the years.</P>

    <P>Quality infrastructure is very important to an open-source project. It prevents disruptions that can greatly delay forward movement of the project.</P>

    <P>Of course, this infrastructure is not cheap. There are a variety of monthly and one-time expenses that are required to keep it going. If you or your company has money it can donate to help fund this effort, please go to <A href="http://www.pgsql.com/pg_goodies">http://www.pgsql.com/pg_goodies</A> and make a donation.</P>

    <P>Although the web page mentions PostgreSQL, Inc, the "contributions" item is solely to support the PostgreSQL project and does not fund any specific company. If you prefer, you can also send a check to the contact address.</P>
    <HR>

    <H2 align="center">User Client Questions</H2>

    <H4><A name="2.1">2.1</A>) Are there <SMALL>ODBC</SMALL> drivers for PostgreSQL?</H4>

    <P>There are two <SMALL>ODBC</SMALL> drivers available, PsqlODBC and OpenLink <SMALL>ODBC</SMALL>.</P>

    <P>PsqlODBC is included in the distribution. More information about it can be gotten from <A href="ftp://ftp.PostgreSQL.org/pub/odbc/">ftp://ftp.PostgreSQL.org/pub/odbc/</A>.</P>

    <P>OpenLink <SMALL>ODBC</SMALL> can be gotten from <A href="http://www.openlinksw.com/">http://www.openlinksw.com</A>. It works with their standard <SMALL>ODBC</SMALL> client software so you'll have PostgreSQL <SMALL>ODBC</SMALL> available on every client platform they support (Win, Mac, Unix, VMS).</P>

    <P>They will probably be selling this product to people who need commercial-quality support, but a freeware version will always be available. Please send questions to <A href="mailto:postgres95@openlink.co.uk">postgres95@openlink.co.uk</A>.</P>

    <P>See also the <A href="http://developer.postgresql.org/docs/postgres/odbc.html">ODBC chapter of the Programmer's Guide</A>.</P>

    <H4><A name="2.2">2.2</A>) What tools are available for using PostgreSQL with Web pages?</H4>

    <P>A nice introduction to Database-backed Web pages can be seen at: <A href="http://www.webreview.com">http://www.webreview.com</A></P>

    <P>There is also one at <A href="http://www.phone.net/home/mwm/hotlist/">http://www.phone.net/home/mwm/hotlist/.</A></P>

    <P>For Web integration, PHP is an excellent interface. It is at <A href="http://www.php.net">http://www.php.net</A>.</P>

    <P>For complex cases, many use the Perl interface and CGI.pm.</P>

    <H4><A name="2.3">2.3</A>) Does PostgreSQL have a graphical user interface? A report generator? An embedded query language interface?</H4>

    <P>We have a nice graphical user interface called <I>pgaccess</I>, which is shipped as part of the distribution. <I>pgaccess</I> also has a report generator. The Web page is <A href="http://www.flex.ro/pgaccess">http://www.flex.ro/pgaccess</A></P>

    <P>We also include <I>ecpg</I>, which is an embedded SQL query language interface for C.</P>

    <H4><A name="2.4">2.4</A>) What languages are available to communicate with PostgreSQL?</H4>

    <P>We have:</P>

    <UL>
      <LI>C (libpq)</LI>

      <LI>C++ (libpq++)</LI>

      <LI>Embedded C (ecpg)</LI>

      <LI>Java (jdbc)</LI>

      <LI>Perl (perl5)</LI>

      <LI>ODBC (odbc)</LI>

      <LI>Python (PyGreSQL)</LI>

      <LI>TCL (libpgtcl)</LI>

      <LI>C Easy API (libpgeasy)</LI>

      <LI>Embedded <SMALL>HTML</SMALL> (<A href="http://www.php.net">PHP from http://www.php.net</A>)</LI>
    </UL>
    <HR>

    <H2 align="center">Administrative Questions</H2>

    <H4><A name="3.1">3.1</A>) How do I install PostgreSQL somewhere other than <I>/usr/local/pgsql</I>?</H4>

    <P>Specify the <I>--prefix</I> option when running <I>configure</I>.</P>

    <H4><A name="3.2">3.2</A>) When I start <I>postmaster</I>, I get a <I>Bad System Call</I> or core dumped message. Why?</H4>

    <P>It could be a variety of problems, but first check to see that you have System V extensions installed in your kernel. PostgreSQL requires kernel support for shared memory and semaphores.</P>

    <H4><A name="3.3">3.3</A>) When I try to start <I>postmaster</I>, I get <I>IpcMemoryCreate</I> errors. Why?</H4>

    <P>You either do not have shared memory configured properly in your kernel or you need to enlarge the shared memory available in the kernel. The exact amount you need depends on your architecture and how many buffers and backend processes you configure for <I>postmaster</I>. For most systems, with default numbers of buffers and processes, you need a minimum of ~1 MB. See the <A href="http://www.postgresql.org/idocs/index.php?kernel-resources.html">PostgreSQL Administrator's Guide</A> for more detailed information about shared memory and semaphores.</P>

    <H4><A name="3.4">3.4</A>) When I try to start <I>postmaster</I>, I get <I>IpcSemaphoreCreate</I> errors. Why?</H4>

    <P>If the error message is <I>IpcSemaphoreCreate: semget failed (No space left on device)</I> then your kernel is not configured with enough semaphores. Postgres needs one semaphore per potential backend process. A temporary solution is to start <I>postmaster</I> with a smaller limit on the number of backend processes. Use <I>-N</I> with a parameter less than the default of 32. A more permanent solution is to increase your kernel's <SMALL>SEMMNS</SMALL> and <SMALL>SEMMNI</SMALL> parameters.</P>

    <P>Inoperative semaphores can also cause crashes during heavy database access.</P>

    <P>If the error message is something else, you might not have semaphore support configured in your kernel at all. See the PostgreSQL Administrator's Guide for more detailed information about shared memory and semaphores.</P>

    <H4><A name="3.5">3.5</A>) How do I prevent other hosts from accessing my PostgreSQL database?</H4>

    <P>By default, PostgreSQL only allows connections from the local machine using Unix domain sockets. Other machines will not be able to connect unless you add the <I>-i</I> flag to <I>postmaster</I>, <B>and</B> enable host-based authentication by modifying the file <I>$PGDATA/pg_hba.conf</I> accordingly. This will allow TCP/IP connections.</P>

    <H4><A name="3.6">3.6</A>) Why can't I connect to my database from another machine?</H4>

    <P>The default configuration allows only Unix domain socket connections from the local machine. To enable TCP/IP connections, make sure <I>postmaster</I> has been started with the <I>-i</I> option, and add an appropriate host entry to the file <I>pgsql/data/pg_hba.conf</I>.</P>

    <H4><A name="3.7">3.7</A>) How do I tune the database engine for better performance?</H4>

    <P>Certainly, indexes can speed up queries. The <SMALL>EXPLAIN</SMALL> command allows you to see how PostgreSQL is interpreting your query, and which indexes are being used.</P>

    <P>If you are doing many <SMALL>INSERTs</SMALL>, consider doing them in a large batch using the <SMALL>COPY</SMALL> command. This is much faster than individual <SMALL>INSERTS.</SMALL> Second, statements not in a <SMALL>BEGIN WORK/COMMIT</SMALL> transaction block are considered to be in their own transaction. Consider performing several statements in a single transaction block. This reduces the transaction overhead. Also, consider dropping and recreating indexes when making large data changes.</P>

    <P>There are several tuning options. You can disable <I>fsync()</I> by starting <I>postmaster</I> with a <I>-o -F</I> option. This will prevent <I>fsync()</I>s from flushing to disk after every transaction.</P>

    <P>You can also use the <I>postmaster</I> <I>-B</I> option to increase the number of shared memory buffers used by the backend processes. If you make this parameter too high, the <I>postmaster</I> may not start because you have exceeded your kernel's limit on shared memory space. Each buffer is 8K and the default is 64 buffers.</P>

    <P>You can also use the backend <I>-S</I> option to increase the maximum amount of memory used by the backend process for temporary sorts. The <I>-S</I> value is measured in kilobytes, and the default is 512 (i.e. 512K).</P>

    <P>You can also use the <SMALL>CLUSTER</SMALL> command to group data in tables to match an index. See the <SMALL>CLUSTER</SMALL> manual page for more details.</P>

    <H4><A name="3.8">3.8</A>) What debugging features are available?</H4>

    <P>PostgreSQL has several features that report status information that can be valuable for debugging purposes.</P>

    <P>First, by running <I>configure</I> with the --enable-cassert option, many <I>assert()</I>s monitor the progress of the backend and halt the program when something unexpected occurs.</P>

    <P>Both <I>postmaster</I> and <I>postgres</I> have several debug options available. First, whenever you start <I>postmaster</I>, make sure you send the standard output and error to a log file, like:</P>
<PRE>
    cd /usr/local/pgsql
    ./bin/postmaster &gt;server.log 2&gt;&amp;1 &amp;
</PRE>

    <P>This will put a server.log file in the top-level PostgreSQL directory. This file contains useful information about problems or errors encountered by the server. <I>Postmaster</I> has a <I>-d</I> option that allows even more detailed information to be reported. The <I>-d</I> option takes a number that specifies the debug level. Be warned that high debug level values generate large log files.</P>

    <P>If <I>postmaster</I> is not running, you can actually run the <I>postgres</I> backend from the command line, and type your <SMALL>SQL</SMALL> statement directly. This is recommended <B>only</B> for debugging purposes. Note that a newline terminates the query, not a semicolon. If you have compiled with debugging symbols, you can use a debugger to see what is happening. Because the backend was not started from <I>postmaster</I>, it is not running in an identical environment and locking/backend interaction problems may not be duplicated.</P>

    <P>If <I>postmaster</I> is running, start <I>psql</I> in one window, then find the <SMALL>PID</SMALL> of the <I>postgres</I> process used by <I>psql</I>. Use a debugger to attach to the <I>postgres</I> <SMALL>PID.</SMALL> You can set breakpoints in the debugger and issue queries from <I>psql</I>. If you are debugging <I>postgres</I> startup, you can set PGOPTIONS="-W n", then start <I>psql</I>. This will cause startup to delay for <I>n</I> seconds so you can attach to the process with the debugger, set any breakpoints, and continue through the startup sequence.</P>

    <P>The <I>postgres</I> program has <I>-s, -A</I>, and <I>-t</I> options that can be very useful for debugging and performance measurements.</P>

    <P>You can also compile with profiling to see what functions are taking execution time. The backend profile files will be deposited in the <I>pgsql/data/base/dbname</I> directory. The client profile file will be put in the client's current directory.</P>

    <H4><A name="3.9">3.9</A>) Why do I get <I>"Sorry, too many clients"</I> when trying to connect?</H4>

    <P>You need to increase <I>postmaster</I>'s limit on how many concurrent backend processes it can start.</P>

    <P>The default limit is 32 processes. You can increase it by restarting <I>postmaster</I> with a suitable <I>-N</I> value or modifying <I>postgresql.conf</I>.</P>

    <P>Note that if you make <I>-N</I> larger than 32, you must also increase <I>-B</I> beyond its default of 64; <I>-B</I> must be at least twice <I>-N</I>, and probably should be more than that for best performance. For large numbers of backend processes, you are also likely to find that you need to increase various Unix kernel configuration parameters. Things to check include the maximum size of shared memory blocks, <SMALL>SHMMAX;</SMALL> the maximum number of semaphores, <SMALL>SEMMNS</SMALL> and <SMALL>SEMMNI;</SMALL> the maximum number of processes, <SMALL>NPROC;</SMALL> the maximum number of processes per user, <SMALL>MAXUPRC;</SMALL> and the maximum number of open files, <SMALL>NFILE</SMALL> and <SMALL>NINODE.</SMALL> The reason that PostgreSQL has a limit on the number of allowed backend processes is so your system won't run out of resources.</P>

    <P>In PostgreSQL versions prior to 6.5, the maximum number of backends was 64, and changing it required a rebuild after altering the MaxBackendId constant in <I>include/storage/sinvaladt.h</I>.</P>

    <H4><A name="3.10">3.10</A>) What are the <I>pg_sorttempNNN.NN</I> files in my database directory?</H4>

    <P>They are temporary files generated by the query executor. For example, if a sort needs to be done to satisfy an <SMALL>ORDER BY,</SMALL> and the sort requires more space than the backend's <I>-S</I> parameter allows, then temporary files are created to hold the extra data.</P>

    <P>The temporary files should be deleted automatically, but might not if a backend crashes during a sort. If you have no backends running at the time, it is safe to delete the pg_tempNNN.NN files.</P>
    <HR>

    <H2 align="center">Operational Questions</H2>

    <H4><A name="4.1">4.1</A>) What is the difference between binary cursors and normal cursors?</H4>

    <P>See the <SMALL>DECLARE</SMALL> manual page for a description.</P>

    <H4><A name="4.2">4.2</A>) How do I <SMALL>SELECT</SMALL> only the first few rows of a query?</H4>

    <P>See the <SMALL>FETCH</SMALL> manual page, or use <SMALL>SELECT</SMALL> ... <SMALL>LIMIT</SMALL>....</P>

    <P>The entire query may have to be evaluated, even if you only want the first few rows. Consider a query that has an <SMALL>ORDER BY.</SMALL> If there is an index that matches the <SMALL>ORDER BY</SMALL>, PostgreSQL may be able to evaluate only the first few records requested, or the entire query may have to be evaluated until the desired rows have been generated.</P>

    <H4><A name="4.3">4.3</A>) How do I get a list of tables or other things I can see in <I>psql</I>?</H4>

    <P>You can read the source code for <I>psql</I> in file <I>pgsql/src/bin/psql/describe.c</I>. It contains <SMALL>SQL</SMALL> commands that generate the output for psql's backslash commands. You can also start <I>psql</I> with the <I>-E</I> option so it will print out the queries it uses to execute the commands you give.</P>

    <H4><A name="4.4">4.4</A>) How do you remove a column from a table?</H4>

    <P>We do not support <SMALL>ALTER TABLE DROP COLUMN,</SMALL> but do this:</P>
<PRE>
    SELECT ...  -- select all columns but the one you want to remove
    INTO TABLE new_table
    FROM old_table;
    DROP TABLE old_table;
    ALTER TABLE new_table RENAME TO old_table;
</PRE>

    <H4><A name="4.5">4.5</A>) What is the maximum size for a row, a table, and a database?</H4>

    <P>These are the limits:</P>
<PRE>
    Maximum size for a database?             unlimited (60 GB databases exist)
    Maximum size for a table?                16 TB
    Maximum size for a row?                  unlimited in 7.1 and later
    Maximum size for a field?                1 GB in 7.1 and later
    Maximum number of rows in a table?       unlimited
    Maximum number of columns in a table?    250-1600 depending on column types
    Maximum number of indexes on a table?    unlimited
</PRE>
    Of course, these are not actually unlimited, but limited to available disk space and memory/swap space. Performance may suffer when these values get unusually large. 

    <P>The maximum table size of 16 TB does not require large file support from the operating system. Large tables are stored as multiple 1 GB files so file system size limits are not important.</P>

    <P>The maximum table size and maximum number of columns can be increased if the default block size is increased to 32k.</P>

    <H4><A name="4.6">4.6</A>) How much database disk space is required to store data from a typical text file?</H4>

    <P>A PostgreSQL database may need six-and-a-half times the disk space required to store the data in a flat file.</P>

    <P>Consider a file of 300,000 lines with two integers on each line. The flat file is 2.4 MB. The size of the PostgreSQL database file containing this data can be estimated at 14 MB:</P>
<PRE>
    36 bytes: each row header (approximate)
   + 8 bytes: two int fields @ 4 bytes each
   + 4 bytes: pointer on page to tuple
   ----------------------------------------
    48 bytes per row

   The data page size in PostgreSQL is 8192 bytes (8 KB), so:

   8192 bytes per page
   -------------------   =  171 rows per database page (rounded up)
     48 bytes per row

   300000 data rows
   --------------------  =  1755 database pages
      171 rows per page

1755 database pages * 8192 bytes per page  =  14,376,960 bytes (14 MB)
</PRE>

    <P>Indexes do not require as much overhead, but do contain the data that is being indexed, so they can be large also.</P>

    <H4><A name="4.7">4.7</A>) How do I find out what tables or indexes are defined in the database?</H4>

    <P><I>psql</I> has a variety of backslash commands to show such information. Use \? to see them.</P>

    <P>Also try the file <I>pgsql/src/tutorial/syscat.source</I>. It illustrates many of the <SMALL>SELECT</SMALL>s needed to get information from the database system tables.</P>

    <H4><A name="4.8">4.8</A>) My queries are slow or don't make use of the indexes. Why?</H4>

    <P>PostgreSQL does not automatically maintain statistics. V<SMALL>ACUUM</SMALL> must be run to update the statistics. After statistics are updated, the optimizer knows how many rows in the table, and can better decide if it should use indexes. Note that the optimizer does not use indexes in cases when the table is small because a sequential scan would be faster.</P>

    <P>For column-specific optimization statistics, use <SMALL>VACUUM ANALYZE.</SMALL> V<SMALL>ACUUM ANALYZE</SMALL> is important for complex multijoin queries, so the optimizer can estimate the number of rows returned from each table, and choose the proper join order. The backend does not keep track of column statistics on its own, so <SMALL>VACUUM ANALYZE</SMALL> must be run to collect them periodically.</P>

    <P>Indexes are usually not used for <SMALL>ORDER BY</SMALL> or joins. A sequential scan followed by an explicit sort is faster than an indexscan of all tuples of a large table. This is because random disk access is very slow.</P>

    <P>When using wild-card operators such as <SMALL>LIKE</SMALL> or <I>~</I>, indexes can only be used if the beginning of the search is anchored to the start of the string. So, to use indexes, <SMALL>LIKE</SMALL> searches should not begin with <I>%</I>, and <I>~</I>(regular expression searches) should start with <I>^</I>.</P>

    <H4><A name="4.9">4.9</A>) How do I see how the query optimizer is evaluating my query?</H4>

    <P>See the <SMALL>EXPLAIN</SMALL> manual page.</P>

    <H4><A name="4.10">4.10</A>) What is an R-tree index?</H4>

    <P>An R-tree index is used for indexing spatial data. A hash index can't handle range searches. A B-tree index only handles range searches in a single dimension. R-trees can handle multi-dimensional data. For example, if an R-tree index can be built on an attribute of type <I>point</I>, the system can more efficiently answer queries such as "select all points within a bounding rectangle."</P>

    <P>The canonical paper that describes the original R-tree design is:</P>

    <P>Guttman, A. "R-trees: A Dynamic Index Structure for Spatial Searching." Proceedings of the 1984 ACM SIGMOD Int'l Conf on Mgmt of Data, 45-57.</P>

    <P>You can also find this paper in Stonebraker's "Readings in Database Systems".</P>

    <P>Built-in R-trees can handle polygons and boxes. In theory, R-trees can be extended to handle higher number of dimensions. In practice, extending R-trees requires a bit of work and we don't currently have any documentation on how to do it.</P>

    <H4><A name="4.11">4.11</A>) What is the Genetic Query Optimizer?</H4>

    <P>The <SMALL>GEQO</SMALL> module speeds query optimization when joining many tables by means of a Genetic Algorithm (GA). It allows the handling of large join queries through nonexhaustive search.</P>

    <H4><A name="4.12">4.12</A>) How do I perform regular expression searches and case-insensitive regular expression searches? How do I use an index for case-insensitive searches?</H4>

    <P>The <I>~</I> operator does regular expression matching, and <I>~*</I> does case-insensitive regular expression matching. The case-insensitive variant of <SMALL>LIKE</SMALL> is called <SMALL>ILIKE</SMALL> in PostgreSQL 7.1 and later.</P>

    <P>Case-insensitive equality comparisons are normally expressed as:</P>
<PRE>
    SELECT *
    FROM tab
    WHERE lower(col) = 'abc'
   
</PRE>
    This will not use an standard index. However, if you create a functional index, it will be used: 
<PRE>
    CREATE INDEX tabindex on tab (lower(col));
   
</PRE>

    <H4><A name="4.13">4.13</A>) In a query, how do I detect if a field is <SMALL>NULL</SMALL>?</H4>

    <P>You test the column with <SMALL>IS NULL</SMALL> and <SMALL>IS NOT NULL</SMALL>.</P>

    <H4><A name="4.14">4.14</A>) What is the difference between the various character types?</H4>
<PRE>
Type            Internal Name   Notes
--------------------------------------------------
"char"          char            1 character
CHAR(#)         bpchar          blank padded to the specified fixed length
VARCHAR(#)      varchar         size specifies maximum length, no padding
TEXT            text            no specific upper limit on length
BYTEA           bytea           variable-length byte array (null-safe)
</PRE>

    <P>You will see the internal name when examining system catalogs and in some error messages.</P>

    <P>The last four types above are "varlena" types (i.e., the first four bytes on disk are the length, followed by the data). Thus the actual space used is slightly greater than the declared size. However, these data types are also subject to compression or being stored out-of-line by <SMALL>TOAST</SMALL>, so the space on disk might also be less than expected.</P>

    <P><SMALL>CHAR()</SMALL> is best when storing strings that are usually the same length. <SMALL>VARCHAR()</SMALL> is best when storing variable-length strings but it limits how long a string can be. <SMALL>TEXT</SMALL> is for strings of unlimited length, maximum 1 gigabyte. <SMALL>BYTEA</SMALL> is for storing binary data, particularly values that include <SMALL>NULL</SMALL> bytes.</P>

    <H4><A name="4.15.1">4.15.1</A>) How do I create a serial/auto-incrementing field?</H4>

    <P>PostgreSQL supports a <SMALL>SERIAL</SMALL> data type. It auto-creates a sequence and index on the column. For example, this:</P>
<PRE>
    CREATE TABLE person ( 
        id   SERIAL, 
        name TEXT 
    );
</PRE>
    is automatically translated into this: 
<PRE>
    CREATE SEQUENCE person_id_seq;
    CREATE TABLE person ( 
        id   INT4 NOT NULL DEFAULT nextval('person_id_seq'),
        name TEXT 
    );
    CREATE UNIQUE INDEX person_id_key ON person ( id );
</PRE>
    See the <I>create_sequence</I> manual page for more information about sequences. You can also use each row's <I>OID</I> field as a unique value. However, if you need to dump and reload the database, you need to use <I>pg_dump</I>'s <I>-o</I> option or <SMALL>COPY WITH OIDS</SMALL> option to preserve the <SMALL>OID</SMALL>s. 

    <H4><A name="4.15.2">4.15.2</A>) How do I get the value of a <SMALL>SERIAL</SMALL> insert?</H4>

    <P>One approach is to retrieve the next <SMALL>SERIAL</SMALL> value from the sequence object with the <I>nextval()</I> function <I>before</I> inserting and then insert it explicitly. Using the example table in <A href="#4.15.1">4.15.1</A>, that might look like this in Perl:</P>
<PRE>
    new_id = output of "SELECT nextval('person_id_seq')"
    INSERT INTO person (id, name) VALUES (new_id, 'Blaise Pascal');
</PRE>
    You would then also have the new value stored in <CODE>new_id</CODE> for use in other queries (e.g., as a foreign key to the <CODE>person</CODE> table). Note that the name of the automatically created <SMALL>SEQUENCE</SMALL> object will be named &lt;<I>table</I>&gt;_&lt;<I>serialcolumn</I>&gt;_<I>seq</I>, where <I>table</I> and <I>serialcolumn</I> are the names of your table and your <SMALL>SERIAL</SMALL> column, respectively. 

    <P>Alternatively, you could retrieve the assigned <SMALL>SERIAL</SMALL> value with the <I>currval</I>() function <I>after</I> it was inserted by default, e.g.,</P>
<PRE>
    INSERT INTO person (name) VALUES ('Blaise Pascal');
    new_id = output of "SELECT currval('person_id_seq')";
</PRE>
    Finally, you could use the <A href="#4.16"><SMALL>OID</SMALL></A> returned from the <SMALL>INSERT</SMALL> statement to look up the default value, though this is probably the least portable approach. In Perl, using DBI with Edmund Mergl's DBD::Pg module, the oid value is made available via <I>$sth-&gt;{pg_oid_status}</I> after <I>$sth-&gt;execute()</I>. 

    <H4><A name="4.15.3">4.15.3</A>) Don't <I>currval()</I> and <I>nextval()</I> lead to a race condition with other users?</H4>

    <P>No. Currval() returns the current value assigned by your backend, not by all users.</P>

    <H4><A name="4.16">4.16</A>) What is an <SMALL>OID</SMALL>? What is a <SMALL>TID</SMALL>?</H4>

    <P><SMALL>OID</SMALL>s are PostgreSQL's answer to unique row ids. Every row that is created in PostgreSQL gets a unique <SMALL>OID</SMALL>. All <SMALL>OID</SMALL>s generated during <I>initdb</I> are less than 16384 (from <I>backend/access/transam.h</I>). All user-created <SMALL>OID</SMALL>s are equal to or greater than this. By default, all these <SMALL>OID</SMALL>s are unique not only within a table or database, but unique within the entire PostgreSQL installation.</P>

    <P>PostgreSQL uses <SMALL>OID</SMALL>s in its internal system tables to link rows between tables. These <SMALL>OID</SMALL>s can be used to identify specific user rows and used in joins. It is recommended you use column type <SMALL>OID</SMALL> to store <SMALL>OID</SMALL> values. You can create an index on the <SMALL>OID</SMALL> field for faster access.</P>

    <P>O<SMALL>ID</SMALL>s are assigned to all new rows from a central area that is used by all databases. If you want to change the <SMALL>OID</SMALL> to something else, or if you want to make a copy of the table, with the original <SMALL>OID</SMALL>s, there is no reason you can't do it:</P>
<PRE>
        CREATE TABLE new_table(old_oid oid, mycol int);
        SELECT old_oid, mycol INTO new FROM old;
        COPY new TO '/tmp/pgtable';
        DELETE FROM new;
        COPY new WITH OIDS FROM '/tmp/pgtable';
<!--
    CREATE TABLE new_table (mycol int);
    INSERT INTO new_table (oid, mycol) SELECT oid, mycol FROM old_table;
-->
</PRE>

    <P>O<SMALL>ID</SMALL>s are stored as 4-byte integers, and will overflow at 4 billion. No one has reported this ever happening, and we plan to have the limit removed before anyone does.</P>

    <P>T<SMALL>ID</SMALL>s are used to identify specific physical rows with block and offset values. T<SMALL>ID</SMALL>s change after rows are modified or reloaded. They are used by index entries to point to physical rows.</P>

    <H4><A name="4.17">4.17</A>) What is the meaning of some of the terms used in PostgreSQL?</H4>

    <P>Some of the source code and older documentation use terms that have more common usage. Here are some:</P>

    <UL>
      <LI>table, relation, class</LI>

      <LI>row, record, tuple</LI>

      <LI>column, field, attribute</LI>

      <LI>retrieve, select</LI>

      <LI>replace, update</LI>

      <LI>append, insert</LI>

      <LI><SMALL>OID</SMALL>, serial value</LI>

      <LI>portal, cursor</LI>

      <LI>range variable, table name, table alias</LI>
    </UL>

    <P>A list of general database terms can be found at: <A href="http://www.comptechnews.com/~reaster/dbdesign.html">http://www.comptechnews.com/~reaster/dbdesign.html</A></P>

    <H4><A name="4.18">4.18</A>) Why do I get the error <I>"ERROR: Memory exhausted in AllocSetAlloc()"</I>?</H4>

    <P>If you are running a version older than 7.1, an upgrade may fix the problem. Also it is possible you have run out of virtual memory on your system, or your kernel has a low limit for certain resources. Try this before starting <I>postmaster</I>:</P>
<PRE>
    ulimit -d 262144
    limit datasize 256m
</PRE>
    Depending on your shell, only one of these may succeed, but it will set your process data segment limit much higher and perhaps allow the query to complete. This command applies to the current process, and all subprocesses created after the command is run. If you are having a problem with the <SMALL>SQL</SMALL> client because the backend is returning too much data, try it before starting the client. 

    <H4><A name="4.19">4.19</A>) How do I tell what PostgreSQL version I am running?</H4>

    <P>From <I>psql</I>, type <CODE>select version();</CODE></P>

    <H4><A name="4.20">4.20</A>) Why does my large-object operations get <I>"invalid large obj descriptor"</I>?</H4>

    <P>You need to put <CODE>BEGIN WORK</CODE> and <CODE>COMMIT</CODE> around any use of a large object handle, that is, surrounding <CODE>lo_open</CODE> ... <CODE>lo_close.</CODE></P>

    <P>Currently PostgreSQL enforces the rule by closing large object handles at transaction commit. So the first attempt to do anything with the handle will draw <I>invalid large obj descriptor</I>. So code that used to work (at least most of the time) will now generate that error message if you fail to use a transaction.</P>

    <P>If you are using a client interface like <SMALL>ODBC</SMALL> you may need to set <CODE>auto-commit off.</CODE></P>

    <H4><A name="4.21">4.21</A>) How do I create a column that will default to the current time?</H4>

    <P>Use <I>CURRENT_TIMESTAMP</I>:</P>
<PRE>
<CODE>CREATE TABLE test (x int, modtime timestamp DEFAULT CURRENT_TIMESTAMP );
</CODE>
</PRE>

    <H4><A name="4.22">4.22</A>) Why are my subqueries using <CODE><SMALL>IN</SMALL></CODE> so slow?</H4>

    <P>Currently, we join subqueries to outer queries by sequentially scanning the result of the subquery for each row of the outer query. A workaround is to replace <CODE>IN</CODE> with <CODE>EXISTS</CODE>:</P>
<PRE>
<CODE>SELECT *
    FROM tab
    WHERE col1 IN (SELECT col2 FROM TAB2)
</CODE>
</PRE>
    to: 
<PRE>
<CODE>SELECT *
    FROM tab
    WHERE EXISTS (SELECT col2 FROM TAB2 WHERE col1 = col2)
</CODE>
</PRE>
    We hope to fix this limitation in a future release. 

    <H4><A name="4.23">4.23</A>) How do I perform an outer join?</H4>

    <P>PostgreSQL 7.1 and later supports outer joins using the SQL standard syntax. Here are two examples:</P>
<PRE>
    SELECT *
    FROM t1 LEFT OUTER JOIN t2 ON (t1.col = t2.col);
</PRE>
    or 
<PRE>
    SELECT *
    FROM t1 LEFT OUTER JOIN t2 USING (col);
</PRE>

    <P>These identical queries join t1.col to t2.col, and also return any unjoined rows in t1 (those with no match in t2). A <SMALL>RIGHT</SMALL> join would add unjoined rows of t2. A <SMALL>FULL</SMALL> join would return the matched rows plus all unjoined rows from t1 and t2. The word <SMALL>OUTER</SMALL> is optional and is assumed in <SMALL>LEFT</SMALL>, <SMALL>RIGHT</SMALL>, and <SMALL>FULL</SMALL> joins. Ordinary joins are called <SMALL>INNER</SMALL> joins.</P>

    <P>In previous releases, outer joins can be simulated using <SMALL>UNION</SMALL> and <SMALL>NOT IN</SMALL>. For example, when joining <I>tab1</I> and <I>tab2</I>, the following query does an <I>outer</I> join of the two tables:<BR>
    <BR>
    </P>
<PRE>
    SELECT tab1.col1, tab2.col2
    FROM tab1, tab2
    WHERE tab1.col1 = tab2.col1
    UNION ALL
    SELECT tab1.col1, NULL
    FROM tab1
    WHERE tab1.col1 NOT IN (SELECT tab2.col1 FROM tab2)
    ORDER BY col1
</PRE>

    <H4><A name="4.24">4.24</A>) How do I perform queries using multiple databases?</H4>

    <P>There is no way to query any database except the current one. Because PostgreSQL loads database-specific system catalogs, it is uncertain how a cross-database query should even behave.</P>

    <P>Of course, a client can make simultaneous connections to different databases and merge the information that way.</P>
    <HR>

    <H2 align="center">Extending PostgreSQL</H2>

    <H4><A name="5.1">5.1</A>) I wrote a user-defined function. When I run it in <I>psql</I>, why does it dump core?</H4>

    <P>The problem could be a number of things. Try testing your user-defined function in a stand-alone test program first.</P>

    <H4><A name="5.2">5.2</A>) How can I contribute some nifty new types and functions to PostgreSQL?</H4>

    <P>Send your extensions to the <I>pgsql-hackers</I> mailing list, and they will eventually end up in the <I>contrib/</I> subdirectory.</P>

    <H4><A name="5.3">5.3</A>) How do I write a C function to return a tuple?</H4>

    <P>This requires wizardry so extreme that the authors have never tried it, though in principle it can be done.</P>

    <H4><A name="5.4">5.4</A>) I have changed a source file. Why does the recompile not see the change?</H4>

    <P>The <I>Makefiles</I> do not have the proper dependencies for include files. You have to do a <I>make clean</I> and then another <I>make</I>. If you are using <SMALL>GCC</SMALL> you can use the <I>--enable-depend</I> option of <I>configure</I> to have the compiler compute the dependencies automatically.</P>
  </BODY>
</HTML>