aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/runtime.sgml
blob: 78978fdb35c70ae770e53bf2b39fc21bc0ef6be6 (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
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/runtime.sgml,v 1.16 2000/07/17 22:32:44 tgl Exp $
-->

<Chapter Id="runtime">
 <Title>Server Runtime Environment</Title>

 <Para>
  This chapter discusses how to set up and run the database server
  and the interactions with the operating system.
 </para>

 <sect1 id="postgres-user">
  <title>The Postgres user account</title>

  <para>
   As with any other server daemon that is connected to the world at
   large, it is advisable to run Postgres under a separate user
   account. This user account should only own the data itself that is
   being managed by the server, and should not be shared with other
   daemons. (Thus, using the user <quote>nobody</quote> is a bad
   idea.) It is not advisable to install the executables as owned by
   this user account because that runs the risk of user-defined
   functions gone astray or any other exploits compromising the
   executable programs.
  </para>

  <para>
   To add a user account to your system, look for a command
   <command>useradd</command> or <command>adduser</command>. The user
   name <quote>postgres</quote> is often used but by no means
   required.
  </para>
 </sect1>

 <sect1 id="creating-cluster">
  <title>Creating a database cluster</title>

  <para>
   Before you can do anything, you must initialize a database storage
   area on disk. We call this a <firstterm>database
   cluster</firstterm>. (<acronym>SQL</acronym> speaks of a catalog
   cluster instead.) A database cluster is a collection of databases
   that will be accessible through a single instance of a running
   database server. After initialization, a database cluster will
   contain one database named <literal>template1</literal>. As the
   name suggests, this will be used as a template for any subsequently
   created database; it should not be used for actual work.
  </para>

  <para>
   In file system terms, a database cluster will be a single directory
   under which all data will be stored. We call this the
   <firstterm>data directory</firstterm> or <firstterm>data
   area</firstterm>. It is completely up to you where you choose to
   store your data, there is no default, although locations such as
   <filename>/usr/local/pgsql/data</filename> or
   <filename>/var/lib/pgsql/data</filename> are popular. To initialize
   a database cluster, use the command <command>initdb</command>,
   which is installed with <productname>PostgreSQL</productname>. The
   desired file system location of your database system is indicated
   by the <option>-D</option> option, for example
<screen>
&gt; <userinput>initdb -D /usr/local/pgsql/data</userinput>
</screen>
   Note that you must execute this command while being logged in to
   the Postgres user account, which is described in the previous
   section.
  </para>

  <tip>
   <para>
    As an alternative to the <option>-D</option> option, you can set
    the environment variable <envar>PGDATA</envar>.
   </para>
  </tip>

  <para>
   <command>initdb</command> will attempt to create the directory you
   specify if it does not already exist. It is likely that it won't
   have the permission to do so (if you followed our advice and
   created an unprivileged account). In that case you can create the
   directory yourself (as root) and transfer ownership of it or grant
   write access to it. Here is how this might work:
<screen>
root# <userinput>mkdir /usr/local/pgsql/data</userinput>
root# <userinput>chown postgres /usr/local/pgsql/data</userinput>
root# <userinput>su postgres</userinput>
postgres&gt; <userinput>initdb -D /usr/local/pgsql/data</userinput>
</screen>
  </para>

  <para>
   <command>initdb</command> will refuse to run if the data directory
   looks like it belongs to an already initialized installation.
  </para>

  <para>
   Because the data directory contains all the data stored in the
   database it is essential that it be well secured from unauthorized
   access. <command>initdb</command> therefore revokes access
   permissions from everyone but the Postgres user account.
  </para>
 </sect1>

 <sect1 id="postmaster-start">
  <title>Starting the database server</title>

  <para>
   Before anyone can access the database you must start the database
   server. The database server is called
   <firstterm>postmaster</firstterm>.
   The postmaster must know where to find the data it is supposed
   to work on. This is done with the <option>-D</option> option. Thus,
   the simplest way to start the server is, for example,
<screen>
&gt; <userinput>postmaster -D /usr/local/pgsql/data</userinput>
</screen>
   which will leave the server running in the foreground. This must
   again be done while logged in to the Postgres user account. Without
   a <option>-D</option>, the server will try to use the data
   directory in the environment variable <envar>PGDATA</envar>; if
   neither of these works it will fail.
  </para>

  <para>
   To start the <application>postmaster</application> in the
   background, use the usual shell syntax:
<screen>
&gt; <userinput>postmaster -D /usr/local/pgsql/data &gt; logfile 1&gt;&amp;2 &amp;</userinput>
</screen>
   It is an extremely good idea to keep the server output around
   somewhere, as indicated here. It will help both for auditing
   purposes and to diagnose problems.
  </para>

  <para>
   The postmaster also takes a number of other command line options.
   For more information see the reference page and below under runtime
   configuration. In particular, in order for the postmaster to accept
   TCP/IP connections (rather than just Unix domain socket ones), you
   must also specify the <option>-i</option> option.
  </para>

  <para>
   Normally, you will want to start the database server when the
   computer boots up. This is not required; the
   <productname>PostgreSQL</productname> server can be run
   successfully from non-privileged accounts without root
   intervention.
  </para>

  <para>
   Different systems have different conventions for starting up
   daemons at boot time, so you are advised to familiarize yourself
   with them. Many systems have a file
   <filename>/etc/rc.local</filename> or
   <filename>/etc/rc.d/rc.local</filename> which is almost certainly
   no bad place to put such a command. Whatever you do, postmaster
   must be run by the <productname>Postgres</productname> user account
   <emphasis>and not by root</emphasis> or any other user. Therefore
   you probably always want to form your command lines along the lines
   of <literal>su -c '...' postgres</literal>, for example:
<programlisting>
nohup su -c 'postmaster -D /usr/local/pgsql/data > server.log 2>&1' postgres &
</programlisting>
   (using the program <application>nohup</application> to prevent the
   server from dying when you log out).
  </para>

  <para>
   Here are a few more operating system specific suggestions.

   <itemizedlist>
    <listitem>
     <para>
      Edit the file <filename>rc.local</filename> on
      <productname>NetBSD</productname> or file
      <filename>rc2.d</filename> on <productname>Solaris</productname> to contain the
      following single line:
<programlisting>
su postgres -c "/usr/local/pgsql/bin/postmaster -D /usr/local/pgsql/data"
</programlisting>
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>FreeBSD</productname> edit
      <filename>/usr/local/etc/rc.d/pgsql.sh</filename> to contain the
      following lines and make it <literal>chmod 755</literal> and
      <literal>chown root:bin</literal>.
<programlisting>
#!/bin/sh
[ -x /usr/local/pgsql/bin/postmaster ] && {
    su -l pgsql -c 'exec /usr/local/pgsql/bin/postmaster
        -D/usr/local/pgsql/data
        -S -o -F > /usr/local/pgsql/errlog' &
    echo -n ' pgsql'
}
</programlisting>
      You may put the line breaks as shown above. The shell is smart
      enough to keep parsing beyond end-of-line if there is an
      expression unfinished. The exec saves one layer of shell under
      the postmaster process so the parent is init.
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>RedHat Linux</productname> add a file
      <filename>/etc/rc.d/init.d/postgres.init</filename> 
       which is based on the example in <filename>contrib/linux/</filename>.
       Then make a softlink to this file from
       <filename>/etc/rc.d/rc5.d/S98postgres.init</filename>.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    While the <application>postmaster</application> is running, it's
    PID is in the file <filename>postmaster.pid</filename> in the data
    directory. This is used as in interlock against multiple running
    postmaster on the same data directory and can also be used for
    shutting down the postmaster.
   </para>

   <para>
    The shell script wrapper <application>pg_ctl</application> that
    comes with <productname>Postgres</productname> can also be used to
    control starting (and stopping!) of the database server in
    intelligent fashion.
   </para>

   <sect2 id="postmaster-start-failures">
    <title>Server Startup Failures</title>

    <para>
     There are several common reasons for the postmaster to fail to
     start up. Check the postmaster's log file, or start it by hand
     (without redirecting standard output or standard error) to see
     what complaint messages appear. Some of the possible error
     messages are reasonably self-explanatory, but here are some that
     are not.
    </para>

    <para>
<screen>
FATAL: StreamServerPort: bind() failed: Address already in use
        Is another postmaster already running on that port?
</screen>
     This usually means just what it suggests: you accidentally
     started a second postmaster on the same port where one is already
     running. However, if the kernel error message is not
     <computeroutput>Address already in use</computeroutput> or some
     variant of that wording, there may be a different problem. For
     example, trying to start a postmaster on a reserved port number
     may draw something like
<screen>
&gt; <userinput>postmaster -i -p 666</userinput>
FATAL: StreamServerPort: bind() failed: Permission denied
        Is another postmaster already running on that port?
</screen>
    </para>

    <para>
     A message like
<screen>
IpcMemoryCreate: shmget(5440001, 83918612, 01600) failed: Invalid argument
FATAL 1:  ShmemCreate: cannot create region
</screen>
     probably means that your kernel's limit on the size of shared
     memory areas is smaller than the buffer area that Postgres is
     trying to create (83918612 bytes in this example). Or it could
     mean that you don't have SysV-style shared memory support
     configured into your kernel at all. As a temporary workaround,
     you can try starting the postmaster with a smaller-than-normal
     number of buffers (<option>-B</option> switch). You will
     eventually want to reconfigure your kernel to increase the
     allowed shared memory size, however. You may see this message
     when trying to start multiple postmasters on the same machine, if
     their total space requests exceed the kernel limit.
    </para>

    <para>
     An error like
<screen>
IpcSemaphoreCreate: semget(5440026, 16, 0600) failed: No space left on device
</screen>
     does <emphasis>not</emphasis> mean that you've run out of disk
     space; it means that your kernel's limit on the number of SysV
     semaphores is smaller than the number
     <productname>Postgres</productname> wants to create. As above,
     you may be able to work around the problem by starting the
     postmaster with a reduced number of backend processes
     (<option>-N</option> switch), but you'll eventually want to
     increase the kernel limit.
    </para>
   </sect2>

   <sect2 id="client-connection-problems">
    <title>Client Connection Problems</title>

    <para>
     Although the possible error conditions on the client side are
     both virtually infinite and application dependent, a few of them
     might be directly related to how the server was started up.
     Conditions other than those shown below should be documented with
     the respective client application.
    </para>

    <para>
<screen>
connectDB() -- connect() failed: Connection refused
Is the postmaster running (with -i) at 'server.joe.com' and accepting connections on TCP/IP port '5432'?
</screen>
     This is the generic <quote>I couldn't find a server to talk
     to</quote> failure. It looks like the above when TCP/IP
     communication is attempted. A common mistake is to forget the
     <option>-i</option> to the postmaster to allow TCP/IP
     connections.
    </para>

    <para>
     Alternatively, you'll get this when attempting
     Unix-socket communication to a local postmaster:
<screen>
connectDB() -- connect() failed: No such file or directory
Is the postmaster running at 'localhost' and accepting connections on Unix socket '5432'?
</screen>
    </para>

    <para>
     The last line is useful in verifying that the client is trying to
     connect where it is supposed to. If there is in fact no
     postmaster running there, the kernel error message will typically
     be either <computeroutput>Connection refused</computeroutput> or
     <computeroutput>No such file or directory</computeroutput>, as
     illustrated. (It is particularly important to realize that
     <computeroutput>Connection refused</computeroutput> in this
     context does <emphasis>not</emphasis> mean that the postmaster
     got your connection request and rejected it -- that case will
     produce a different message, as shown in <xref
     linkend="client-authentication-problems">.) Other error messages
     such as <computeroutput>Connection timed out</computeroutput> may
     indicate more fundamental problems, like lack of network
     connectivity.
    </para>
   </sect2>
  </sect1>

  <sect1 Id="runtime-config">
   <Title>Run-time configuration</Title>

   <para>
    There are a lot of configuration parameters that affect the
    behavior of the database system in some way or other. Here we
    describe how to set them and the following subsections will
    discuss each of them.
   </para>

   <para>
    All parameter names are case-insensitive. Every parameter takes a
    value of one of the four types boolean, integer, floating point,
    string as described below. Boolean values are
    <literal>ON</literal>, <literal>OFF</literal>,
    <literal>TRUE</literal>, <literal>FALSE</literal>,
    <literal>YES</literal>, <literal>NO</literal>,
    <literal>1</literal>, <literal>0</literal> (case-insensitive) or
    any non-ambiguous prefix of these.
   </para>

   <para>
    One way to set these options is to create a file
    <filename>postgresql.conf</filename> in the data directory (e.g.,
    <filename>/usr/local/pgsql/data</filename>). An example of what
    this file could look like is:
<programlisting>
# This is a comment
log_connections = yes
syslog = 2
</programlisting>
    As you see, options are one per line. The equal sign between name
    and value is optional. White space is insignificant, blank lines
    are ignored. Hash marks (<quote>#</quote>) introduce comments
    anywhere.
   </para>

   <para>
    The configuration file is reread whenever the postmaster receives
    a SIGHUP signal. This signal is also propagated to all running
    backend processes, so that running sessions get the new default.
    Alternatively, you can send the signal to only one backend process
    directly.
   </para>

   <para>
    A second way to set these configuration parameters is to give them
    as a command line option to the postmaster, such as
<programlisting>
postmaster --log-connections=yes --syslog=2
</programlisting>
    which would have the same effect as the previous example.
   </para>

   <para>
    Occasionally it is also useful to give a command line option to
    one particular backend session only. The environment variable
    <envar>PGOPTIONS</envar> can be used for this purpose on the
    client side:
<programlisting>
env PGOPTIONS='--geqo=off' psql
</programlisting>
    (This works for any client application, not just
    <application>psql</application>.) Note that this won't work for
    options that are necessarily fixed once the server is started,
    such as the port number.
   </para>

   <para>
    Finally, some options can be changed in individual SQL sessions
    with the <command>SET</command> command, for example
<screen>
=&gt; <userinput>SET ENABLE_SEQSCAN TO OFF;</userinput>
</screen>
    See the SQL command language reference for details on the syntax.
   </para>

   <sect2 id="runtime-config-optimizer">
    <title>Planner and Optimizer Tuning</title>

   <para>
    <variablelist>
     <varlistentry>
      <term>CPU_INDEX_TUPLE_COST (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of processing
	each index tuple during an index scan. This is measured as a
	fraction of the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term>CPU_OPERATOR_COST (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the optimizer's estimate of the cost of processing each
	operator in a WHERE clause. This is measured as a fraction of
	the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term>CPU_TUPLE_COST (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of processing
	each tuple during a query. This is measured as a fraction of
	the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term>EFFECTIVE_CACHE_SIZE (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the optimizer's assumption about the effective size of
	the disk cache (that is, the portion of the kernel's disk
	cache that will be used for
	<productname>Postgres</productname> data files). This is
	measured in disk pages, which are normally 8kB apiece.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_HASHJOIN (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of hash-join plan
        types. The default is on. This is mostly useful to debug the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_INDEXSCAN (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of index scan plan
        types. The default is on. This is mostly useful to debug the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_MERGEJOIN (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of merge-join plan
        types. The default is on. This is mostly useful to debug the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_NESTLOOP (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of nested-loop
	join plans. It's not possible to suppress nested-loop joins
	entirely, but turning this variable off discourages the
	planner from using one if there is any other method available.
	The default is on. This is mostly useful to debug the query
	planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_SEQSCAN (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of sequential scan
	plan types. It's not possible to suppress sequential scans
	entirely, but turning this variable off discourages the
	planner from using one if there is any other method available.
	The default is on. This is mostly useful to debug the query
	planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_SORT (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of explicit sort
	steps. It's not possible to suppress explicit sorts entirely,
	but turning this variable off discourages the planner from
	using one if there is any other method available. The default
	is on. This is mostly useful to debug the query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ENABLE_TIDSCAN (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of TID scan plan
        types. The default is on. This is mostly useful to debug the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>GEQO (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables genetic query optimization, which is an
        algorithm that attempts to do query planning without
        exhaustive search. This is on by default. See also the various
        other GEQO_ settings.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>GEQO_EFFORT (<type>integer</type>)</term>
      <term>GEQO_GENERATIONS (<type>integer</type>)</term>
      <term>GEQO_POOL_SIZE (<type>integer</type>)</term>
      <term>GEQO_RANDOM_SEED (<type>integer</type>)</term>
      <term>GEQO_SELECTION_BIAS (<type>floating point</type>)</term>
      <listitem>
       <para>
        Various tuning parameters for the genetic query optimization
        algorithm: The pool size is the number of individuals in one
        population. Valid values are between 128 and 1024. If it is
        set to 0 (the default) a pool size of 2^(QS+1), where QS
        is the number of relations in the query, is taken. The effort
        is used to calculate a default for generations. Valid values
        are between 1 and 80, 40 being the default. Generations
        specifies the number of iterations in the algorithm. The
        number must be a positive integer. If 0 is specified then
        Effort * Log2(PoolSize) is used. The run time of the algorithm
        is roughly proportional to the sum of pool size and
        generations. The selection bias is the selective pressure
        within the population. Values can be from 1.50 to 2.00; the
        latter is the default. The random seed can be set to get
        reproduceable results from the algorithm. If it is set to -1
        then the algorithm behaves non-deterministically.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>GEQO_RELS (<type>integer</type>)</term>
      <listitem>
       <para>
        Only use genetic query optimization for queries with at least
        this many relations involved. The default is 11. For less
        relations it is probably more efficient to use the
        deterministic, exhaustive planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>KSQO (<type>boolean</type>)</term>
      <listitem>
       <para>
        The <firstterm>Key Set Query Optimizer</firstterm>
        (<abbrev>KSQO</abbrev>) causes the query planner to convert
        queries whose WHERE clause contains many OR'ed AND clauses
        (such as <literal>WHERE (a=1 AND b=2) OR (a=2 AND b=3)
        ...</literal>) into a UNION query. This method can be faster
        than the default implementation, but it doesn't necessarily
        give exactly the same results, since UNION implicitly adds a
        SELECT DISTINCT clause to eliminate identical output rows.
        KSQO is commonly used when working with products like
        <productname>Microsoft Access</productname>, which tend to
        generate queries of this form.
       </para>

       <para>
        The KSQO algorithm used to be absolutely essential for queries
        with many OR'ed AND clauses, but in
        <productname>Postgres</productname> 7.0 and later the standard
        planner handles these queries fairly successfully. Hence the
        default is OFF.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>RANDOM_PAGE_COST (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of a
	nonsequentially fetched disk page. This is measured as a
	multiple of the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>

   <note>
    <para>
     Unfortunately, there is no well-defined method of determining
     ideal values for the family of <quote>COST</quote> variables that
     were just described. You are encouraged to experiment and share
     your findings.
    </para>
   </note>

   </sect2>

   <sect2 id="logging">
    <title>Logging and Debugging</title>

   <para>
    <variablelist>
     <varlistentry>
      <term>DEBUG_ASSERTIONS (<type>boolean</type>)</term>
      <listitem>
       <para>
        Turns on various assertion checks. This is a debugging aid. If
        you are experiencing strange problems or crashes you might
        want to turn this on, as it might expose programming mistakes.
        To use this option, the macro <literal>USE_ASSERT_CHECKING</>
        must be defined when Postgres is built.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>DEBUG_LEVEL (<type>integer</type>)</term>
      <listitem>
       <para>
        The higher this value is set, the more
        <quote>debugging</quote> output of various sorts is generated
        in the server log during operation. This option is 0 by
        default, which means no debugging output. Values up to about 4
        currently make sense.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>DEBUG_PRINT_PARSE (<type>boolean</type>)</term>
      <term>DEBUG_PRINT_PLAN (<type>boolean</type>)</term>
      <term>DEBUG_PRINT_REWRITTEN (<type>boolean</type>)</term>
      <term>DEBUG_PRINT_QUERY (<type>boolean</type>)</term>
      <term>DEBUG_PRETTY_PRINT (<type>boolean</type>)</term>
      <listitem>
       <para>
        For any executed query, prints either the query, the parse
        tree, the execution plan, or the query rewriter output to the
        server log. <option>DEBUG_PRETTY_PRINT</option> selects are
        nicer but longer output format.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>HOSTLOOKUP (<type>boolean</type>)</term>
      <listitem>
       <para>
        By default, connection logs only show the IP address of the
        connecting host. If you want it to show the host name you can
        turn this on, but depending on your host name resolution setup
        it might impose a non-negligible performance penalty. This
        option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>LOG_CONNECTIONS (<type>boolean</type>)</term>
      <listitem>
       <para>
        Prints a line informing about each successful connection to
        the server log. This is off by default, although it is
        probably very useful. This option can only be set at server
        start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>LOG_PID (<type>boolean</type>)</term>
      <listitem>
       <para>
        Prefixes each server log message with the process id of the
        backend process. This is useful to sort out which messages
        pertain to which connection. The default is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>LOG_TIMESTAMP (<type>boolean</type>)</term>
      <listitem>
       <para>
        Prefixes each server log message with a timestamp. The default
        is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHOW_QUERY_STATS (<type>boolean</type>)</term>
      <term>SHOW_PARSER_STATS (<type>boolean</type>)</term>
      <term>SHOW_PLANNER_STATS (<type>boolean</type>)</term>
      <term>SHOW_EXECUTOR_STATS (<type>boolean</type>)</term>
      <listitem>
       <para>
        For each query, write performance statistics of the respective
        module to the server log. This is a crude profiling
        instrument.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHOWPORTNUMBER (<type>boolean</type>)</term>
      <listitem>
       <para>
        Shows the port number of the connecting host in the connection
        log messages. You could trace back the port number to find out
        what user initiated the connection. Other than that it's
        pretty useless and therefore off by default. This option can
        only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SYSLOG (<type>integer</type>)</term>
      <listitem>
       <para>
        <productname>Postgres</productname> allows the use of
        <application>syslog</application> for logging. If this option
        is set to 1, messages go both to syslog and the standard
        output. A setting of 2 sends output only to syslog. (Some
        messages will still go to the standard output/error.) The
        default is 0, which means syslog is off. This option must be
        set at server start.
       </para>
       <para>
        To use syslog, the build of
        <productname>Postgres</productname> must be configured with
        the <option>--enable-syslog</option> option.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>TRACE_NOTIFY (<type>boolean</type>)</term>
      <listitem>
       <para>
        Generates a great amount of debugging output for the
        <command>LISTEN</command> and <command>NOTIFY</command>
        commands.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
   </sect2>

   <sect2 id="runtime-config-general">
    <title>General operation</title>

   <para>
    <variablelist>
     <varlistentry>
      <term>DEADLOCK_TIMEOUT (<type>integer</type>)</term>
      <listitem>
       <para>
        This is the amount of time, in milliseconds, to wait on a lock
	before checking to see if there is a deadlock condition or not.
	The check for deadlock is relatively slow, so we don't want to
	run it every time we wait for a lock.  We (optimistically?)
	assume that deadlocks are not common in production applications,
	and just wait on the lock for awhile before starting to ask
	questions about whether it can ever get unlocked.
	Increasing this value reduces the amount of time wasted in
	needless deadlock checks, but slows down reporting of real deadlock
	errors.  The default is 1000 (i.e., one second), which is probably
	about the smallest value you would want in practice.  On a heavily
	loaded server you might want to raise it.  Ideally the setting
	should exceed your typical transaction time, so as to improve the
	odds that the lock will be released before the waiter decides to
	check for deadlock. 
	This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>FSYNC (<type>boolean</type>)</term>
      <listitem>
       <para>
        If this is option is on, the <productname>Postgres</> backend
        will use the <function>fsync()</> system call in several
        places to make sure that updates are physically written to
        disk and will not hang around in the write caches. This
        increases the chance that a database installation will still
        be usable after a operating system or hardware crashes by a
        large amount. (Crashes of the database server itself do
        <emphasis>not</> affect this consideration.)
       </para>

       <para>
        However, this operation severely slows down
        <productname>Postgres</>, because at all those points it has
        to block and wait for the operating system to flush the
        buffers. Without <function>fsync</>, the operating system is
        allowed to do its best in buffering, sorting, and delaying
        writes, so this can be a <emphasis>very</> big perfomance
        increase. However, if the system crashes, parts of the data of
        a transaction that has already been committed -- according to
        the information on disk -- will still hang around in memory.
        Inconsistent data (i.e., data corruption) is therefore likely
        to occur.
       </para>

       <para>
        This option is the subject of an eternal debate in the
        <productname>Postgres</> user and developer communities. Some
        always leave it off, some turn it off only for bulk loads,
        where there is a clear restart point if something goes wrong,
        some leave it on just to be on the safe side. Because it is
        the safe side, on is also the default. If you trust your
        operating system, your utility company, and your hardware, you
        might want to disable it.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>MAX_CONNECTIONS (<type>integer</type>)</term>
      <listitem>
       <para>
        Determines how many concurrent connections the database server
        will allow. The default is 32. There is also a compiled-in
        hard upper limit on this value, which is typically 1024
	(both numbers can be altered when compiling the server). This
        parameter can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>MAX_EXPR_DEPTH (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the maximum expression nesting depth that the parser will
	accept. The default value is high enough for any normal query,
	but you can raise it if you need to. (But if you raise it too
	high, you run the risk of backend crashes due to stack
	overflow.)
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>TCPIP_SOCKET (<type>boolean</type>)</term>
      <listitem>
       <para>
        If this is true, then the server will accept TCP/IP
        connections. Otherwise only local Unix domain socket
        connections are accepted. It is off by default. This option
        can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>PORT (<type>integer</type>)</term>
      <listitem>
       <para>
        The TCP port the server listens on; 5432 by default. This
        option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHMEM_BUFFERS (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the number of shared memory buffers the database server
        will use. The default is 64. Each buffer is typically 8192
        bytes. This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SORT_MEM (<type>integer</type>)</term>
      <listitem>
       <para>
	Specifies the amount of memory to be used by internal sorts
	and hashes before resorting to temporary disk files. The value
	is specified in kilobytes, and defaults to 512 kilobytes. Note
	that for a complex query, several sorts and/or hashes might be
	running in parallel, and each one will be allowed to use as
	much memory as this value specifies before it starts to put
	data into temporary files.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SQL_INHERITANCE (<type>bool</type>)</term>
      <listitem>
       <para>
        This controls the inheritance semantics, in particular whether
        subtables are included into the consideration of various
        commands by default. This was not the case in versions prior
        to 7.1. If you need the old behaviour you can set this
        variable to off, but in the long run you are encouraged to
        change your applications to use the <literal>ONLY</literal>
        keyword to exclude subtables. See the SQL language reference
        and the <citetitle>User's Guide</citetitle> for more
        information about inheritance.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
   </sect2>

   <sect2 id="runtime-config-short">
    <title>Short options</title>
   <para>
    For convenience there are also single letter option switches
    available for many parameters. They are described in the following
    table.

    <table>
     <title>Short option key</title>
     <tgroup cols="3">
      <colspec colnum="3" align="center">
      <thead>
       <row>
        <entry>Short option</entry>
        <entry>Equivalent</entry>
        <entry>Remark</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry>-B <replaceable>x</replaceable></entry>
        <entry>shmem_buffers = <replaceable>x</replaceable></entry>
        <entry></entry>
       </row>
       <row>
        <entry>-d <replaceable>x</replaceable></entry>
        <entry>debug_level = <replaceable>x</replaceable></entry>
        <entry></entry>
       </row>
       <row>
        <entry>-F</entry>
        <entry>fsync = off</entry>
        <entry></entry>
       </row>
       <row>
        <entry>-i</entry>
        <entry>tcpip_socket = on</entry>
        <entry></entry>
       </row>
       <row>
        <entry>-N <replaceable>x</replaceable></entry>
        <entry>max_connections = <replaceable>x</replaceable></entry>
        <entry></entry>
       </row>
       <row>
        <entry>-p <replaceable>x</replaceable></entry>
        <entry>port = <replaceable>x</replaceable></entry>
        <entry></entry>
       </row>

       <row>
        <entry>-fi, -fh, -fm, -fn, -fs, -ft</entry>
        <entry>enable_indexscan=off, enable_hashjoin=off,
        enable_mergejoin=off, enable_nestloop=off, enable_seqscan=off,
        enable_tidscan=off</entry>
        <entry>*</entry>
       </row>
       <row>
        <entry>-S <replaceable>x</replaceable></entry>
        <entry>sort_mem = <replaceable>x</replaceable></entry>
        <entry>*</entry>
       </row>
       <row>
        <entry>-s</entry>
        <entry>show_query_stats = on</entry>
        <entry>*</entry>
       </row>
       <row>
        <entry>-tpa, -tpl, -te</entry>
        <entry>show_parser_stats=on, show_planner_stats=on, show_executor_stats=on</entry>
        <entry>*</entry>
       </row>
      </tbody>
     </tgroup>
    </table>
    For historical reasons, options marked <quote>*</quote> must be
    passed to the individual backend process via the
    <option>-o</option> postmaster option, for example,
<screen>
&gt; <userinput>postmaster -o '-S 1024 -s'</userinput>
</screen>
    or via <envar>PGOPTIONS</envar> from the client side, as explained
    above.
   </para>

   </sect2>
 </sect1>


 <sect1 id="locale">
  <title>Locale Support</title>
  
  <note>
   <title>Acknowledgement</title>
   <para>
    Written by Oleg Bartunov. See <ulink
    url="http://www.sai.msu.su/~megera/postgres/">Oleg's web
    page</ulink> for additional information on locale and Russian
    language support.
   </para>
  </note>

  <para>
   While doing a project for a company in Moscow, Russia, I
   encountered the problem that <productname>Postgres</> had no
   support of national alphabets. After looking for possible
   workarounds I decided to develop support of locale myself. I'm not
   a C programmer but already had some experience with locale
   programming when I work with <productname>Perl</> (debugging) and
   <productname>Glimpse</>. After several days of digging through the
   <productname>Postgres</> source tree I made very minor corections
   to <filename>src/backend/utils/adt/varlena.c</> and
   <filename>src/backend/main/main.c</> and got what I needed! I did
   support only for <envar>LC_CTYPE</envar> and
   <envar>LC_COLLATE</envar>, but later <envar>LC_MONETARY</envar> was
   added by others. I got many messages from people about this patch
   so I decided to send it to developers and (to my surprise) it was
   incorporated into the <productname>Postgres</> distribution.
  </para>

  <para>
   People often complain that locale doesn't work for them. There are
   several common mistakes:
   
   <itemizedlist>
    <listitem>
     <para>
      Didn't properly configure <productname>Postgres</> before
      compilation. You must run <filename>configure</> with the
      <option>--enable-locale</> option to enable locale support.
     </para>
    </listitem>

    <listitem>
     <para>
      Didn't setup environment correctly when starting postmaster. You
      must define environment variables <envar>LC_CTYPE</envar> and
      <envar>LC_COLLATE</envar> before running postmaster because
      backend gets information about locale from environment. I use
      following shell script:
<programlisting>
#!/bin/sh

export LC_CTYPE=koi8-r
export LC_COLLATE=koi8-r
postmaster -B 1024 -S -D/usr/local/pgsql/data/ -o '-Fe'
</programlisting>
     </para>
    </listitem>

    <listitem>
     <para>
      Broken locale support in the operating system (for example,
      locale support in libc under Linux several times has changed and
      this caused a lot of problems). Perl has also support of locale
      and if locale is broken <command>perl -v</> will complain
      something like:
<screen>
8:17[mira]:~/WWW/postgres>setenv LC_CTYPE not_exist
8:18[mira]:~/WWW/postgres>perl -v
perl: warning: Setting locale failed.
perl: warning: Please check that your locale settings:
LC_ALL = (unset),
LC_CTYPE = "not_exist",
LANG = (unset)
are supported and installed on your system.
perl: warning: Falling back to the standard locale ("C").
</screen>
     </para>
    </listitem>

    <listitem>
     <para>
      Wrong location of locale files. Possible locations include:
      <filename>/usr/lib/locale</filename> (Linux, Solaris),
      <filename>/usr/share/locale</filename> (Linux),
      <filename>/usr/lib/nls/loc</filename> (DUX 4.0).
      
      Check <command>man locale</command> to find the correct
      location. Under Linux I made a symbolic link between
      <filename>/usr/lib/locale</filename> and
      <filename>/usr/share/locale</filename> to be sure that the next
      libc will not break my locale.
     </para>
    </listitem>
   </itemizedlist>
  </para>

  <formalpara>
   <title>What are the Benefits?</title> 
   <para>
    You can use ~* and order by operators for strings contain
    characters from national alphabets. Non-english users definitely
    need that.
   </para>
  </formalpara>

  <formalpara>
   <title>What are the Drawbacks?</title>
   <para>
    There is one evident drawback of using locale - its speed! So, use
    locale only if you really need it.
   </para>
  </formalpara>
 </sect1>


 <sect1 id="postmaster-shutdown">
  <title>Shutting down the server</title>

  <para>
   Depending on your needs, there are several ways to shut down the
   database server when your work is done. The differentiation is
   done by what signal you send to the server process.
   <variablelist>
    <varlistentry>
     <term>SIGTERM</term>
     <listitem>
      <para>
       After receiving SIGTERM, the postmaster disallows new
       connections but lets active backend end their work and shuts
       down only after all of them terminated (by client request).
       This is the <firstterm>Smart Shutdown</firstterm>.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>SIGINT</term>
     <listitem>
      <para>
       The postmaster disallows new connections, sends all active
       backends SIGTERM (which will cause them to abort immediately),
       waits for children to exit and shuts down the data base. This
       is the <firstterm>Fast Shutdown</firstterm>.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>SIGQUIT</term>
     <listitem>
      <para>
       This is the <firstterm>Immediate Shutdown</firstterm> which
       will cause the postmaster to send a SIGUSR1 to all backends and
       exit immediately (without properly shutting down the database
       system). When WAL is implemented, this will lead to recovery on
       startup. Right now it's not recommendable to use this option.
      </para>
     </listitem>
    </varlistentry>
   </variablelist>

   <caution>
    <para>
     If at all possible, do not use SIGKILL to shut down the
     postmaster. This can cause data corruption and will prevent the
     cleaning up of shared memory resources, which you will have to
     do yourself in that case.
    </para>
   </caution>

   The PID of the postmaster process can be found using the
   <application>ps</application> program, or from the file
   <filename>postmaster.pid</filename> in the data directory. So for
   example, to do a fast shutdown:
<screen>
&gt; <userinput>kill -INT `cat /usr/local/pgsql/data/postmaster.pid`</userinput>
</screen>
  </para>
  <para>
   The program <application>pg_ctl</application> is a shell script
   wrapper that provides a convenient interface to these functions.
  </para>
 </sect1>

 <sect1>
  <title>Secure TCP/IP Connection with SSH</title>

  <note>
   <title>Acknowledgement</title>
   <para>
    Idea taken from an email by Gene Selkov, Jr.
    (<email>selkovjr@mcs.anl.gov</>) written on 1999-09-08 in response
    to a question from Eric Marsden.
   </para>
  </note>

  <para>
   One can use <productname>ssh</productname> to encrypt the network
   connection between clients and a
   <productname>Postgres</productname> server. Done properly, this
   should lead to an adequately secure network connection.
  </para>

  <para>
   First make sure that an <productname>ssh</productname> server is
   running properly on the same machine as
   <productname>Postgres</productname> and that you can log in using
   ssh as some user. Then you can establish a secure tunnel with a
   command like this from the client machine:
<programlisting>
&gt; <userinput>ssh -L 3333:foo.com:5432 joe@foo.com</userinput>
</programlisting>
   The first number in the <option>-L</option> argument, 3333, is the
   port number of your end of the tunnel; it can be chosen freely. The
   second number, 5432, is the remote end of the tunnel -- the port
   number your backend is using. The name or the address in between
   the port numbers is the host with the database server you are going
   to connect to. In order to connect to the database server using
   this tunnel, you connect to port 3333 on the local machine:
<programlisting>
psql -h localhost -p 3333 template1
</programlisting>
   To the database server it will then look as though you are really
   user <literal>joe@foo.com</literal> and it will use whatever
   authentication procedure was set up for this user. In order for the
   tunnel setup to succeed you must be allowed to connect via ssh as
   joe@foo.com, just as if you had attempted to use ssh to set up a
   terminal session.
  </para>

 </sect1>

</Chapter>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->