File: postgresql.conf.5

package info (click to toggle)
postgresql 7.4.7-6sarge6
  • links: PTS
  • area: main
  • in suites: sarge
  • size: 11,168 kB
  • ctags: 27
  • sloc: sh: 1,903; makefile: 337; ansic: 204; perl: 69; sed: 6; tcl: 1
file content (533 lines) | stat: -rw-r--r-- 20,725 bytes parent folder | download | duplicates (2)
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
.TH postgresql.conf 5 "20th August 2001" PostgreSQL ""
.SH NAME
postgresql.conf \- PostgreSQL backend configuration file
.SH DESCRIPTION
.PP
.I /etc/postgresql/postgresql.conf
is a configuration file for the PostgreSQL
backend.  All the options it supports are described below.  Some of these
must be defined in postgresql.conf, so that they are available when
PostgreSQL is started, but others can also be changed by run-time commands.
.PP
An example of what this file could look like is:
.pp
.RS
# This is a comment
.br
log_connections = yes
.br
syslog = 2
.RE
.PP
Options are one per line. The equal sign between name
and value is optional. White space is insignificant, blank lines
are ignored. Hash marks (#) introduce comments
anywhere. Option names are not case-sensitive.
.PP
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.
.PP
A second way to set these configuration parameters is to give them
as a command line option to the postmaster, such as
.RS
postmaster -c log_connections=yes -c syslog=2
.RE
which would have the same effect as the previous example.
Command-line options override any conflicting settings in
postgresql.conf.
.PP
Occasionally it is also useful to give a command line option to
one particular backend session only. The environment variable
PGOPTIONS can be used for this purpose on the
client side:
.RS
env PGOPTIONS='-c geqo=off' psql
.RE
.PP
(This works for any client application, not just
psql.) Note that this won't work for
options that are necessarily fixed once the server is started,
such as the port number.
.PP
Finally, some options can be changed in individual SQL sessions
with the SET command, for example
.RS
SET ENABLE_SEQSCAN TO OFF;
.RE
.PP
See the SQL command language reference for details on the syntax.
.SH Planner and Optimizer Tuning
.TP
.BR CPU_INDEX_TUPLE_COST " (floating point)"
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.
.TP
.BR CPU_OPERATOR_COST " (floating point)"
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.
.TP
.BR CPU_TUPLE_COST " (floating point)"
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.
.TP
.BR EFFECTIVE_CACHE_SIZE " (floating point)"
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
Postgres data files). This is
measured in disk pages, which are normally 8kB apiece.
.TP
.BR ENABLE_HASHJOIN " (boolean)"
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.
.TP
.BR ENABLE_INDEXSCAN " (boolean)"
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.
.TP
.BR ENABLE_MERGEJOIN " (boolean)"
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.
.TP
.BR ENABLE_NESTLOOP " (boolean)"
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.
.TP
.BR ENABLE_SEQSCAN " (boolean)"
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.
.TP
.BR ENABLE_SORT " (boolean)"
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.
.TP
.BR ENABLE_TIDSCAN " (boolean)"
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.
.TP
.BR GEQO " (boolean)"
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.
.TP
.BR GEQO_EFFORT " (integer)"
.BR GEQO_GENERATIONS " (integer)"
.BR GEQO_POOL_SIZE " (integer)"
.BR GEQO_RANDOM_SEED " (integer)"
.BR GEQO_SELECTION_BIAS " (floating point)"
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 FROM items 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.
.TP
.BR GEQO_THRESHOLD " (integer)"
Use genetic query optimization to plan queries with at least
this many FROM items involved.  (Note that a JOIN construct
counts as only one FROM item.) The default is 11. For simpler
queries it is usually best to use the
deterministic, exhaustive planner.
.TP
.BR KSQO " (boolean)"
The Key Set Query Optimizer
(KSQO) causes the query planner to convert
queries whose WHERE clause contains many OR'ed AND clauses
(such as WHERE (a=1 AND b=2) OR (a=2 AND b=3)
...) 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
Microsoft Access, which tend to
generate queries of this form.

The KSQO algorithm used to be absolutely essential for queries
with many OR'ed AND clauses, but in
Postgres 7.0 and later the standard
planner handles these queries fairly successfully. Hence the
default is OFF.
.TP
.BR RANDOM_PAGE_COST " (floating point)"
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.

Unfortunately, there is no well-defined method of determining
ideal values for the family of COST variables that
were just described. You are encouraged to experiment and share
your findings.
.SH Logging and Debugging
.TP
.BR DEBUG_ASSERTIONS " (boolean)"
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 USE_ASSERT_CHECKING
must be defined when Postgres is built (see the configure option
--enable-cassert).  Note that
DEBUG_ASSERTIONS defaults to ON if Postgres
has been built this way.
.TP
.BR DEBUG_LEVEL " (integer)"
The higher this value is set, the more
debugging 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.
.TP
.BR DEBUG_PRINT_QUERY " (boolean)"
.TP
.BR DEBUG_PRINT_PARSE " (boolean)"
.TP
.BR DEBUG_PRINT_REWRITTEN " (boolean)"
.TP
.BR DEBUG_PRINT_PLAN " (boolean)"
.TP
.BR DEBUG_PRETTY_PRINT " (boolean)"
These flags enable various debugging output to be sent to the
server log.  For each executed query, prints either the query text,
the resulting parse tree, the query rewriter output, or the execution
plan. DEBUG_PRETTY_PRINT indents these displays
to produce a more readable but much longer output format.
Setting DEBUG_LEVEL above zero implicitly turns
on some of these flags.
.TP
.BR HOSTNAME_LOOKUP " (boolean)"
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.
.TP
.BR LOG_CONNECTIONS " (boolean)"
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.
.TP
.BR LOG_PID " (boolean)"
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.
.TP
.BR LOG_TIMESTAMP " (boolean)"
Prefixes each server log message with a timestamp. The default
is off.
.TP
.BR SHOW_QUERY_STATS " (boolean)"
.TP
.BR SHOW_PARSER_STATS " (boolean)"
.TP
.BR SHOW_PLANNER_STATS " (boolean)"
.TP
.BR SHOW_EXECUTOR_STATS " (boolean)"
For each query, write performance statistics of the respective
module to the server log. This is a crude profiling
instrument.
.TP
.BR SHOW_SOURCE_PORT " (boolean)"
Shows the outgoing 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.
.TP
.BR SYSLOG " (integer)"
Postgres allows the use of
syslog 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.

For syslog to be used, the build of
Postgres must have been configured with
the --enable-syslog option.
.TP
.BR SYSLOG_FACILITY " (string)"
This option determines the syslog
facility to be used when syslog is enabled.
You may choose from LOCAL0, LOCAL1, LOCAL2, LOCAL3, LOCAL4,
LOCAL5, LOCAL6, LOCAL7; the default is LOCAL0.  See also the
documentation of your system's
syslog.
.TP
.BR SYSLOG_IDENT " (string)"
If logging to syslog is enabled, this option determines the
program name used to identify
PostgreSQL messages in
syslog log messages.  The default
is postgres.
.TP
.BR TRACE_NOTIFY " (boolean)"
Generates a great amount of debugging output for the
LISTEN and NOTIFY
commands.

.SH General operation
.TP
.BR DEADLOCK_TIMEOUT " (integer)"
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.
.TP
.BR FSYNC " (boolean)"
If this option is on, the Postgres backend
will use the fsync() system call in several
places to make sure that updates are physically written to
disk and do not hang around in the kernel buffer cache. This
increases the chance that a database installation will still
be usable after an operating system or hardware crash by a
large amount. (Crashes of the database server itself do
not affect this consideration.)

However, this operation slows down Postgres,
because at all those points it has
to block and wait for the operating system to flush the
buffers. Without fsync, the operating system is
allowed to do its best in buffering, sorting, and delaying
writes, which can make for a considerable perfomance
increase. However, if the system crashes, the results of the
last few committed transactions may be lost in part or whole;
in the worst case, unrecoverable data corruption may occur.

This option is the subject of an eternal debate in the
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 hardware, and your utility company (or
better your UPS), you might want to disable fsync.

It should be noted that the performance penalty from doing
fsyncs is considerably less in Postgres version
7.1 than it was in prior releases.  If you previously suppressed
fsyncs because of performance problems, you may wish to reconsider
your choice.

This option can only be set at server start or in the
.I postgresql.conf
file.
.TP
.BR KRB_SERVER_KEYFILE " (string)"
Sets the location of the Kerberos server key file. See
for details.
.TP
.BR MAX_CONNECTIONS " (integer)"
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.
.TP
.BR MAX_EXPR_DEPTH " (integer)"
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.)
.TP
.BR PORT " (integer)"
The TCP port the server listens on; 5432 by default. This
option can only be set at server start.
.TP
.BR SHARED_BUFFERS " (integer)"
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.
.TP
.BR SILENT_MODE " (boolean)"
Runs postmaster silently. If this option is set, postmaster
will automatically run in background and any controlling ttys
are disassociated, thus no messages are written to stdout or
stderr (same effect as postmaster's -S option). Unless some
logging system such as syslog is enabled, using this option is
discouraged since it makes it impossible to see error
messages.
.TP
.BR SORT_MEM " (integer)"
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.  And don't forget that each running
backend could be doing one or more sorts.  So the total memory
space needed could be many times the value of SORT_MEM.
.TP
.BR SQL_INHERITANCE " (boolean)"
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 ONLY
keyword to exclude subtables. See the SQL language reference
and the User's Guide for more
information about inheritance.
.TP
.BR SSL " (boolean)"
Enables SSL connections. Please read
before using this. The default
is off.
.TP
.BR TCPIP_SOCKET " (boolean)"
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.
.TP
.BR UNIX_SOCKET_DIRECTORY " (string)"
Specifies the directory of the Unix-domain socket on which the
postmaster is to listen for
connections from client applications.  The default is normally
/tmp, but can be changed at build time.
.TP
.BR UNIX_SOCKET_GROUP " (string)"
Sets the group owner of the Unix domain socket.  (The owning
user of the socket is always the user that starts the
postmaster.)  In combination with the option
UNIX_SOCKET_PERMISSIONS this can be used as
an additional access control mechanism for this socket type.
By default this is the empty string, which uses the default
group for the current user.  This option can only be set at
server start.
.TP
.BR UNIX_SOCKET_PERMISSIONS " (integer)"
Sets the access permissions of the Unix domain socket.  Unix
domain sockets use the usual Unix file system permission set.
The option value is expected to be an numeric mode
specification in the form accepted by the
chmod and umask
system calls.  (To use the customary octal format the number
must start with a 0 (zero).)

The default permissions are 0777, meaning
anyone can connect.  Reasonable alternatives would be
0770 (only user and group, see also under
UNIX_SOCKET_GROUP) and
0700 (only user).  (Note that actually for
a Unix socket, only write permission matters and there is no
point in setting or revoking read or execute permissions.)

This access control mechanism is independent from the one
described in .

This option can only be set at server start.
.TP
.BR VIRTUAL_HOST " (string)"
Specifies the TCP/IP hostname or address on which the
postmaster is to listen for
connections from client applications.  Defaults to
listening on all configured addresses (including localhost).

.SH WAL (Write-ahead logging)
.TP
.BR CHECKPOINT_SEGMENTS " (integer)"
Maximum distance between automatic WAL checkpoints, in logfile
segments (each segment is normally 16 megabytes).
This option can only be set at server start or in the
postgresql.conf file.
.TP
.BR CHECKPOINT_TIMEOUT " (integer)"
Maximum time between automatic WAL checkpoints, in seconds.
This option can only be set at server start or in the
postgresql.conf file.
.TP
.BR COMMIT_DELAY " (integer)"
Time delay between writing a commit record to the WAL buffer and
flushing the buffer out to disk, in microseconds.  A nonzero delay
allows multiple transactions to be committed with only one fsync,
if system load is high enough that additional transactions become
ready to commit within the given interval.  But the delay is just
wasted time if no other transactions become ready to commit.
Therefore, the delay is only performed if at least COMMIT_SIBLINGS
other transactions are active at the instant that a backend has
written its commit record.
.TP
.BR COMMIT_SIBLINGS " (integer)"
Minimum number of concurrent open transactions to require before
performing the COMMIT_DELAY delay.  A larger value makes it more
probable that at least one other transaction will become ready to
commit during the delay interval.
.TP
.BR WAL_BUFFERS " (integer)"
Number of disk-page buffers in shared memory for WAL log.
This option can only be set at server start.
.TP
.BR WAL_DEBUG " (integer)"
If non-zero, turn on WAL-related debugging output on standard
error.
.TP
.BR WAL_FILES " (integer)"
Number of log files that are created in advance at checkpoint
time.  This option can only be set at server start or in the
postgresql.conf file.
.TP
.BR WAL_SYNC_METHOD " (string)"
Method used for forcing WAL updates out to disk.  Possible
values are
.br
FSYNC (call fsync() at each commit),
.br
FDATASYNC (call fdatasync() at each commit),
.br
OPEN_SYNC (write WAL files with open() option O_SYNC), or
.br
OPEN_DATASYNC (write WAL files with open() option O_DSYNC).

Not all of these choices are available on all platforms.
This option can only be set at server start or in the
postgresql.conf file.
.SH SEE ALSO
.BR postmaster "(1), " postgres "(1), " set "(7l)"