1PG_DUMP(1) PostgreSQL 9.2.24 Documentation PG_DUMP(1)
2
3
4
6 pg_dump - extract a PostgreSQL database into a script file or other
7 archive file
8
10 pg_dump [connection-option...] [option...] [dbname]
11
13 pg_dump is a utility for backing up a PostgreSQL database. It makes
14 consistent backups even if the database is being used concurrently.
15 pg_dump does not block other users accessing the database (readers or
16 writers).
17
18 Dumps can be output in script or archive file formats. Script dumps are
19 plain-text files containing the SQL commands required to reconstruct
20 the database to the state it was in at the time it was saved. To
21 restore from such a script, feed it to psql(1). Script files can be
22 used to reconstruct the database even on other machines and other
23 architectures; with some modifications, even on other SQL database
24 products.
25
26 The alternative archive file formats must be used with pg_restore(1) to
27 rebuild the database. They allow pg_restore to be selective about what
28 is restored, or even to reorder the items prior to being restored. The
29 archive file formats are designed to be portable across architectures.
30
31 When used with one of the archive file formats and combined with
32 pg_restore, pg_dump provides a flexible archival and transfer
33 mechanism. pg_dump can be used to backup an entire database, then
34 pg_restore can be used to examine the archive and/or select which parts
35 of the database are to be restored. The most flexible output file
36 format is the “custom” format (-Fc). It allows for selection and
37 reordering of all archived items, and is compressed by default.
38
39 While running pg_dump, one should examine the output for any warnings
40 (printed on standard error), especially in light of the limitations
41 listed below.
42
44 The following command-line options control the content and format of
45 the output.
46
47 dbname
48 Specifies the name of the database to be dumped. If this is not
49 specified, the environment variable PGDATABASE is used. If that is
50 not set, the user name specified for the connection is used.
51
52 -a, --data-only
53 Dump only the data, not the schema (data definitions). Table data,
54 large objects, and sequence values are dumped.
55
56 This option is similar to, but for historical reasons not identical
57 to, specifying --section=data.
58
59 -b, --blobs
60 Include large objects in the dump. This is the default behavior
61 except when --schema, --table, or --schema-only is specified. The
62 -b switch is therefore only useful to add large objects to dumps
63 where a specific schema or table has been requested. Note that
64 blobs are considered data and therefore will be included when
65 --data-only is used, but not when --schema-only is.
66
67 -c, --clean
68 Output commands to clean (drop) database objects prior to
69 outputting the commands for creating them. (Restore might generate
70 some harmless error messages, if any objects were not present in
71 the destination database.)
72
73 This option is only meaningful for the plain-text format. For the
74 archive formats, you can specify the option when you call
75 pg_restore.
76
77 -C, --create
78 Begin the output with a command to create the database itself and
79 reconnect to the created database. (With a script of this form, it
80 doesn't matter which database in the destination installation you
81 connect to before running the script.) If --clean is also
82 specified, the script drops and recreates the target database
83 before reconnecting to it.
84
85 This option is only meaningful for the plain-text format. For the
86 archive formats, you can specify the option when you call
87 pg_restore.
88
89 -E encoding, --encoding=encoding
90 Create the dump in the specified character set encoding. By
91 default, the dump is created in the database encoding. (Another way
92 to get the same result is to set the PGCLIENTENCODING environment
93 variable to the desired dump encoding.)
94
95 -f file, --file=file
96 Send output to the specified file. This parameter can be omitted
97 for file based output formats, in which case the standard output is
98 used. It must be given for the directory output format however,
99 where it specifies the target directory instead of a file. In this
100 case the directory is created by pg_dump and must not exist before.
101
102 -F format, --format=format
103 Selects the format of the output. format can be one of the
104 following:
105
106 p, plain
107 Output a plain-text SQL script file (the default).
108
109 c, custom
110 Output a custom-format archive suitable for input into
111 pg_restore. Together with the directory output format, this is
112 the most flexible output format in that it allows manual
113 selection and reordering of archived items during restore. This
114 format is also compressed by default.
115
116 d, directory
117 Output a directory-format archive suitable for input into
118 pg_restore. This will create a directory with one file for each
119 table and blob being dumped, plus a so-called Table of Contents
120 file describing the dumped objects in a machine-readable format
121 that pg_restore can read. A directory format archive can be
122 manipulated with standard Unix tools; for example, files in an
123 uncompressed archive can be compressed with the gzip tool. This
124 format is compressed by default.
125
126 t, tar
127 Output a tar-format archive suitable for input into pg_restore.
128 The tar format is compatible with the directory format:
129 extracting a tar-format archive produces a valid
130 directory-format archive. However, the tar format does not
131 support compression. Also, when using tar format the relative
132 order of table data items cannot be changed during restore.
133
134 -i, --ignore-version
135 A deprecated option that is now ignored.
136
137 -n schema, --schema=schema
138 Dump only schemas matching schema; this selects both the schema
139 itself, and all its contained objects. When this option is not
140 specified, all non-system schemas in the target database will be
141 dumped. Multiple schemas can be selected by writing multiple -n
142 switches. Also, the schema parameter is interpreted as a pattern
143 according to the same rules used by psql's \d commands (see
144 Patterns), so multiple schemas can also be selected by writing
145 wildcard characters in the pattern. When using wildcards, be
146 careful to quote the pattern if needed to prevent the shell from
147 expanding the wildcards; see EXAMPLES.
148
149 Note
150 When -n is specified, pg_dump makes no attempt to dump any
151 other database objects that the selected schema(s) might depend
152 upon. Therefore, there is no guarantee that the results of a
153 specific-schema dump can be successfully restored by themselves
154 into a clean database.
155
156 Note
157 Non-schema objects such as blobs are not dumped when -n is
158 specified. You can add blobs back to the dump with the --blobs
159 switch.
160
161 -N schema, --exclude-schema=schema
162 Do not dump any schemas matching the schema pattern. The pattern is
163 interpreted according to the same rules as for -n. -N can be given
164 more than once to exclude schemas matching any of several patterns.
165
166 When both -n and -N are given, the behavior is to dump just the
167 schemas that match at least one -n switch but no -N switches. If -N
168 appears without -n, then schemas matching -N are excluded from what
169 is otherwise a normal dump.
170
171 -o, --oids
172 Dump object identifiers (OIDs) as part of the data for every table.
173 Use this option if your application references the OID columns in
174 some way (e.g., in a foreign key constraint). Otherwise, this
175 option should not be used.
176
177 -O, --no-owner
178 Do not output commands to set ownership of objects to match the
179 original database. By default, pg_dump issues ALTER OWNER or SET
180 SESSION AUTHORIZATION statements to set ownership of created
181 database objects. These statements will fail when the script is run
182 unless it is started by a superuser (or the same user that owns all
183 of the objects in the script). To make a script that can be
184 restored by any user, but will give that user ownership of all the
185 objects, specify -O.
186
187 This option is only meaningful for the plain-text format. For the
188 archive formats, you can specify the option when you call
189 pg_restore.
190
191 -R, --no-reconnect
192 This option is obsolete but still accepted for backwards
193 compatibility.
194
195 -s, --schema-only
196 Dump only the object definitions (schema), not data.
197
198 This option is the inverse of --data-only. It is similar to, but
199 for historical reasons not identical to, specifying
200 --section=pre-data --section=post-data.
201
202 (Do not confuse this with the --schema option, which uses the word
203 “schema” in a different meaning.)
204
205 To exclude table data for only a subset of tables in the database,
206 see --exclude-table-data.
207
208 -S username, --superuser=username
209 Specify the superuser user name to use when disabling triggers.
210 This is only relevant if --disable-triggers is used. (Usually, it's
211 better to leave this out, and instead start the resulting script as
212 superuser.)
213
214 -t table, --table=table
215 Dump only tables (or views or sequences or foreign tables) matching
216 table. Multiple tables can be selected by writing multiple -t
217 switches. Also, the table parameter is interpreted as a pattern
218 according to the same rules used by psql's \d commands (see
219 Patterns), so multiple tables can also be selected by writing
220 wildcard characters in the pattern. When using wildcards, be
221 careful to quote the pattern if needed to prevent the shell from
222 expanding the wildcards; see EXAMPLES.
223
224 The -n and -N switches have no effect when -t is used, because
225 tables selected by -t will be dumped regardless of those switches,
226 and non-table objects will not be dumped.
227
228 Note
229 When -t is specified, pg_dump makes no attempt to dump any
230 other database objects that the selected table(s) might depend
231 upon. Therefore, there is no guarantee that the results of a
232 specific-table dump can be successfully restored by themselves
233 into a clean database.
234
235 Note
236 The behavior of the -t switch is not entirely upward compatible
237 with pre-8.2 PostgreSQL versions. Formerly, writing -t tab
238 would dump all tables named tab, but now it just dumps
239 whichever one is visible in your default search path. To get
240 the old behavior you can write -t '*.tab'. Also, you must write
241 something like -t sch.tab to select a table in a particular
242 schema, rather than the old locution of -n sch -t tab.
243
244 -T table, --exclude-table=table
245 Do not dump any tables matching the table pattern. The pattern is
246 interpreted according to the same rules as for -t. -T can be given
247 more than once to exclude tables matching any of several patterns.
248
249 When both -t and -T are given, the behavior is to dump just the
250 tables that match at least one -t switch but no -T switches. If -T
251 appears without -t, then tables matching -T are excluded from what
252 is otherwise a normal dump.
253
254 -v, --verbose
255 Specifies verbose mode. This will cause pg_dump to output detailed
256 object comments and start/stop times to the dump file, and progress
257 messages to standard error.
258
259 -V, --version
260 Print the pg_dump version and exit.
261
262 -x, --no-privileges, --no-acl
263 Prevent dumping of access privileges (grant/revoke commands).
264
265 -Z 0..9, --compress=0..9
266 Specify the compression level to use. Zero means no compression.
267 For the custom archive format, this specifies compression of
268 individual table-data segments, and the default is to compress at a
269 moderate level. For plain text output, setting a nonzero
270 compression level causes the entire output file to be compressed,
271 as though it had been fed through gzip; but the default is not to
272 compress. The tar archive format currently does not support
273 compression at all.
274
275 --binary-upgrade
276 This option is for use by in-place upgrade utilities. Its use for
277 other purposes is not recommended or supported. The behavior of the
278 option may change in future releases without notice.
279
280 --column-inserts, --attribute-inserts
281 Dump data as INSERT commands with explicit column names (INSERT
282 INTO table (column, ...) VALUES ...). This will make restoration
283 very slow; it is mainly useful for making dumps that can be loaded
284 into non-PostgreSQL databases. However, since this option generates
285 a separate command for each row, an error in reloading a row causes
286 only that row to be lost rather than the entire table contents.
287
288 --disable-dollar-quoting
289 This option disables the use of dollar quoting for function bodies,
290 and forces them to be quoted using SQL standard string syntax.
291
292 --disable-triggers
293 This option is only relevant when creating a data-only dump. It
294 instructs pg_dump to include commands to temporarily disable
295 triggers on the target tables while the data is reloaded. Use this
296 if you have referential integrity checks or other triggers on the
297 tables that you do not want to invoke during data reload.
298
299 Presently, the commands emitted for --disable-triggers must be done
300 as superuser. So, you should also specify a superuser name with -S,
301 or preferably be careful to start the resulting script as a
302 superuser.
303
304 This option is only meaningful for the plain-text format. For the
305 archive formats, you can specify the option when you call
306 pg_restore.
307
308 --exclude-table-data=table
309 Do not dump data for any tables matching the table pattern. The
310 pattern is interpreted according to the same rules as for -t.
311 --exclude-table-data can be given more than once to exclude tables
312 matching any of several patterns. This option is useful when you
313 need the definition of a particular table even though you do not
314 need the data in it.
315
316 To exclude data for all tables in the database, see --schema-only.
317
318 --inserts
319 Dump data as INSERT commands (rather than COPY). This will make
320 restoration very slow; it is mainly useful for making dumps that
321 can be loaded into non-PostgreSQL databases. However, since this
322 option generates a separate command for each row, an error in
323 reloading a row causes only that row to be lost rather than the
324 entire table contents. Note that the restore might fail altogether
325 if you have rearranged column order. The --column-inserts option is
326 safe against column order changes, though even slower.
327
328 --lock-wait-timeout=timeout
329 Do not wait forever to acquire shared table locks at the beginning
330 of the dump. Instead fail if unable to lock a table within the
331 specified timeout. The timeout may be specified in any of the
332 formats accepted by SET statement_timeout. (Allowed values vary
333 depending on the server version you are dumping from, but an
334 integer number of milliseconds is accepted by all versions since
335 7.3. This option is ignored when dumping from a pre-7.3 server.)
336
337 --no-security-labels
338 Do not dump security labels.
339
340 --no-tablespaces
341 Do not output commands to select tablespaces. With this option, all
342 objects will be created in whichever tablespace is the default
343 during restore.
344
345 This option is only meaningful for the plain-text format. For the
346 archive formats, you can specify the option when you call
347 pg_restore.
348
349 --no-unlogged-table-data
350 Do not dump the contents of unlogged tables. This option has no
351 effect on whether or not the table definitions (schema) are dumped;
352 it only suppresses dumping the table data. Data in unlogged tables
353 is always excluded when dumping from a standby server.
354
355 --quote-all-identifiers
356 Force quoting of all identifiers. This option is recommended when
357 dumping a database from a server whose PostgreSQL major version is
358 different from pg_dump's, or when the output is intended to be
359 loaded into a server of a different major version. By default,
360 pg_dump quotes only identifiers that are reserved words in its own
361 major version. This sometimes results in compatibility issues when
362 dealing with servers of other versions that may have slightly
363 different sets of reserved words. Using --quote-all-identifiers
364 prevents such issues, at the price of a harder-to-read dump script.
365
366 --section=sectionname
367 Only dump the named section. The section name can be pre-data,
368 data, or post-data. This option can be specified more than once to
369 select multiple sections. The default is to dump all sections.
370
371 The data section contains actual table data, large-object contents,
372 and sequence values. Post-data items include definitions of
373 indexes, triggers, rules, and constraints other than validated
374 check constraints. Pre-data items include all other data definition
375 items.
376
377 --serializable-deferrable
378 Use a serializable transaction for the dump, to ensure that the
379 snapshot used is consistent with later database states; but do this
380 by waiting for a point in the transaction stream at which no
381 anomalies can be present, so that there isn't a risk of the dump
382 failing or causing other transactions to roll back with a
383 serialization_failure. See Chapter 13, Concurrency Control, in the
384 documentation for more information about transaction isolation and
385 concurrency control.
386
387 This option is not beneficial for a dump which is intended only for
388 disaster recovery. It could be useful for a dump used to load a
389 copy of the database for reporting or other read-only load sharing
390 while the original database continues to be updated. Without it the
391 dump may reflect a state which is not consistent with any serial
392 execution of the transactions eventually committed. For example, if
393 batch processing techniques are used, a batch may show as closed in
394 the dump without all of the items which are in the batch appearing.
395
396 This option will make no difference if there are no read-write
397 transactions active when pg_dump is started. If read-write
398 transactions are active, the start of the dump may be delayed for
399 an indeterminate length of time. Once running, performance with or
400 without the switch is the same.
401
402 --use-set-session-authorization
403 Output SQL-standard SET SESSION AUTHORIZATION commands instead of
404 ALTER OWNER commands to determine object ownership. This makes the
405 dump more standards-compatible, but depending on the history of the
406 objects in the dump, might not restore properly. Also, a dump using
407 SET SESSION AUTHORIZATION will certainly require superuser
408 privileges to restore correctly, whereas ALTER OWNER requires
409 lesser privileges.
410
411 -?, --help
412 Show help about pg_dump command line arguments, and exit.
413
414 The following command-line options control the database connection
415 parameters.
416
417 -h host, --host=host
418 Specifies the host name of the machine on which the server is
419 running. If the value begins with a slash, it is used as the
420 directory for the Unix domain socket. The default is taken from the
421 PGHOST environment variable, if set, else a Unix domain socket
422 connection is attempted.
423
424 -p port, --port=port
425 Specifies the TCP port or local Unix domain socket file extension
426 on which the server is listening for connections. Defaults to the
427 PGPORT environment variable, if set, or a compiled-in default.
428
429 -U username, --username=username
430 User name to connect as.
431
432 -w, --no-password
433 Never issue a password prompt. If the server requires password
434 authentication and a password is not available by other means such
435 as a .pgpass file, the connection attempt will fail. This option
436 can be useful in batch jobs and scripts where no user is present to
437 enter a password.
438
439 -W, --password
440 Force pg_dump to prompt for a password before connecting to a
441 database.
442
443 This option is never essential, since pg_dump will automatically
444 prompt for a password if the server demands password
445 authentication. However, pg_dump will waste a connection attempt
446 finding out that the server wants a password. In some cases it is
447 worth typing -W to avoid the extra connection attempt.
448
449 --role=rolename
450 Specifies a role name to be used to create the dump. This option
451 causes pg_dump to issue a SET ROLErolename command after connecting
452 to the database. It is useful when the authenticated user
453 (specified by -U) lacks privileges needed by pg_dump, but can
454 switch to a role with the required rights. Some installations have
455 a policy against logging in directly as a superuser, and use of
456 this option allows dumps to be made without violating the policy.
457
459 PGDATABASE, PGHOST, PGOPTIONS, PGPORT, PGUSER
460 Default connection parameters.
461
462 This utility, like most other PostgreSQL utilities, also uses the
463 environment variables supported by libpq (see Section 31.14,
464 “Environment Variables”, in the documentation).
465
467 pg_dump internally executes SELECT statements. If you have problems
468 running pg_dump, make sure you are able to select information from the
469 database using, for example, psql(1). Also, any default connection
470 settings and environment variables used by the libpq front-end library
471 will apply.
472
473 The database activity of pg_dump is normally collected by the
474 statistics collector. If this is undesirable, you can set parameter
475 track_counts to false via PGOPTIONS or the ALTER USER command.
476
478 If your database cluster has any local additions to the template1
479 database, be careful to restore the output of pg_dump into a truly
480 empty database; otherwise you are likely to get errors due to duplicate
481 definitions of the added objects. To make an empty database without any
482 local additions, copy from template0 not template1, for example:
483
484 CREATE DATABASE foo WITH TEMPLATE template0;
485
486 When a data-only dump is chosen and the option --disable-triggers is
487 used, pg_dump emits commands to disable triggers on user tables before
488 inserting the data, and then commands to re-enable them after the data
489 has been inserted. If the restore is stopped in the middle, the system
490 catalogs might be left in the wrong state.
491
492 The dump file produced by pg_dump does not contain the statistics used
493 by the optimizer to make query planning decisions. Therefore, it is
494 wise to run ANALYZE after restoring from a dump file to ensure optimal
495 performance; see Section 23.1.3, “Updating Planner Statistics”, in the
496 documentation and Section 23.1.6, “The Autovacuum Daemon”, in the
497 documentation for more information. The dump file also does not contain
498 any ALTER DATABASE ... SET commands; these settings are dumped by
499 pg_dumpall(1), along with database users and other installation-wide
500 settings.
501
502 Because pg_dump is used to transfer data to newer versions of
503 PostgreSQL, the output of pg_dump can be expected to load into
504 PostgreSQL server versions newer than pg_dump's version. pg_dump can
505 also dump from PostgreSQL servers older than its own version.
506 (Currently, servers back to version 7.0 are supported.) However,
507 pg_dump cannot dump from PostgreSQL servers newer than its own major
508 version; it will refuse to even try, rather than risk making an invalid
509 dump. Also, it is not guaranteed that pg_dump's output can be loaded
510 into a server of an older major version — not even if the dump was
511 taken from a server of that version. Loading a dump file into an older
512 server may require manual editing of the dump file to remove syntax not
513 understood by the older server. Use of the --quote-all-identifiers
514 option is recommended in cross-version cases, as it can prevent
515 problems arising from varying reserved-word lists in different
516 PostgreSQL versions.
517
519 To dump a database called mydb into a SQL-script file:
520
521 $ pg_dump mydb > db.sql
522
523 To reload such a script into a (freshly created) database named newdb:
524
525 $ psql -d newdb -f db.sql
526
527 To dump a database into a custom-format archive file:
528
529 $ pg_dump -Fc mydb > db.dump
530
531 To dump a database into a directory-format archive:
532
533 $ pg_dump -Fd mydb -f dumpdir
534
535 To reload an archive file into a (freshly created) database named
536 newdb:
537
538 $ pg_restore -d newdb db.dump
539
540 To dump a single table named mytab:
541
542 $ pg_dump -t mytab mydb > db.sql
543
544 To dump all tables whose names start with emp in the detroit schema,
545 except for the table named employee_log:
546
547 $ pg_dump -t 'detroit.emp*' -T detroit.employee_log mydb > db.sql
548
549 To dump all schemas whose names start with east or west and end in gsm,
550 excluding any schemas whose names contain the word test:
551
552 $ pg_dump -n 'east*gsm' -n 'west*gsm' -N '*test*' mydb > db.sql
553
554 The same, using regular expression notation to consolidate the
555 switches:
556
557 $ pg_dump -n '(east|west)*gsm' -N '*test*' mydb > db.sql
558
559 To dump all database objects except for tables whose names begin with
560 ts_:
561
562 $ pg_dump -T 'ts_*' mydb > db.sql
563
564 To specify an upper-case or mixed-case name in -t and related switches,
565 you need to double-quote the name; else it will be folded to lower case
566 (see Patterns). But double quotes are special to the shell, so in turn
567 they must be quoted. Thus, to dump a single table with a mixed-case
568 name, you need something like
569
570 $ pg_dump -t '"MixedCaseName"' mydb > mytab.sql
571
573 pg_dumpall(1), pg_restore(1), psql(1)
574
575
576
577PostgreSQL 9.2.24 2017-11-06 PG_DUMP(1)