1PG_DUMP(1)               PostgreSQL 13.3 Documentation              PG_DUMP(1)
2
3
4

NAME

6       pg_dump - extract a PostgreSQL database into a script file or other
7       archive file
8

SYNOPSIS

10       pg_dump [connection-option...] [option...] [dbname]
11

DESCRIPTION

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       pg_dump only dumps a single database. To back up an entire cluster, or
19       to back up global objects that are common to all databases in a cluster
20       (such as roles and tablespaces), use pg_dumpall(1).
21
22       Dumps can be output in script or archive file formats. Script dumps are
23       plain-text files containing the SQL commands required to reconstruct
24       the database to the state it was in at the time it was saved. To
25       restore from such a script, feed it to psql(1). Script files can be
26       used to reconstruct the database even on other machines and other
27       architectures; with some modifications, even on other SQL database
28       products.
29
30       The alternative archive file formats must be used with pg_restore(1) to
31       rebuild the database. They allow pg_restore to be selective about what
32       is restored, or even to reorder the items prior to being restored. The
33       archive file formats are designed to be portable across architectures.
34
35       When used with one of the archive file formats and combined with
36       pg_restore, pg_dump provides a flexible archival and transfer
37       mechanism.  pg_dump can be used to backup an entire database, then
38       pg_restore can be used to examine the archive and/or select which parts
39       of the database are to be restored. The most flexible output file
40       formats are the “custom” format (-Fc) and the “directory” format (-Fd).
41       They allow for selection and reordering of all archived items, support
42       parallel restoration, and are compressed by default. The “directory”
43       format is the only format that supports parallel dumps.
44
45       While running pg_dump, one should examine the output for any warnings
46       (printed on standard error), especially in light of the limitations
47       listed below.
48

OPTIONS

50       The following command-line options control the content and format of
51       the output.
52
53       dbname
54           Specifies the name of the database to be dumped. If this is not
55           specified, the environment variable PGDATABASE is used. If that is
56           not set, the user name specified for the connection is used.
57
58       -a
59       --data-only
60           Dump only the data, not the schema (data definitions). Table data,
61           large objects, and sequence values are dumped.
62
63           This option is similar to, but for historical reasons not identical
64           to, specifying --section=data.
65
66       -b
67       --blobs
68           Include large objects in the dump. This is the default behavior
69           except when --schema, --table, or --schema-only is specified. The
70           -b switch is therefore only useful to add large objects to dumps
71           where a specific schema or table has been requested. Note that
72           blobs are considered data and therefore will be included when
73           --data-only is used, but not when --schema-only is.
74
75       -B
76       --no-blobs
77           Exclude large objects in the dump.
78
79           When both -b and -B are given, the behavior is to output large
80           objects, when data is being dumped, see the -b documentation.
81
82       -c
83       --clean
84           Output commands to clean (drop) database objects prior to
85           outputting the commands for creating them. (Unless --if-exists is
86           also specified, restore might generate some harmless error
87           messages, if any objects were not present in the destination
88           database.)
89
90           This option is ignored when emitting an archive (non-text) output
91           file. For the archive formats, you can specify the option when you
92           call pg_restore.
93
94       -C
95       --create
96           Begin the output with a command to create the database itself and
97           reconnect to the created database. (With a script of this form, it
98           doesn't matter which database in the destination installation you
99           connect to before running the script.) If --clean is also
100           specified, the script drops and recreates the target database
101           before reconnecting to it.
102
103           With --create, the output also includes the database's comment if
104           any, and any configuration variable settings that are specific to
105           this database, that is, any ALTER DATABASE ... SET ...  and ALTER
106           ROLE ... IN DATABASE ... SET ...  commands that mention this
107           database. Access privileges for the database itself are also
108           dumped, unless --no-acl is specified.
109
110           This option is ignored when emitting an archive (non-text) output
111           file. For the archive formats, you can specify the option when you
112           call pg_restore.
113
114       -E encoding
115       --encoding=encoding
116           Create the dump in the specified character set encoding. By
117           default, the dump is created in the database encoding. (Another way
118           to get the same result is to set the PGCLIENTENCODING environment
119           variable to the desired dump encoding.)
120
121       -f file
122       --file=file
123           Send output to the specified file. This parameter can be omitted
124           for file based output formats, in which case the standard output is
125           used. It must be given for the directory output format however,
126           where it specifies the target directory instead of a file. In this
127           case the directory is created by pg_dump and must not exist before.
128
129       -F format
130       --format=format
131           Selects the format of the output.  format can be one of the
132           following:
133
134           p
135           plain
136               Output a plain-text SQL script file (the default).
137
138           c
139           custom
140               Output a custom-format archive suitable for input into
141               pg_restore. Together with the directory output format, this is
142               the most flexible output format in that it allows manual
143               selection and reordering of archived items during restore. This
144               format is also compressed by default.
145
146           d
147           directory
148               Output a directory-format archive suitable for input into
149               pg_restore. This will create a directory with one file for each
150               table and blob being dumped, plus a so-called Table of Contents
151               file describing the dumped objects in a machine-readable format
152               that pg_restore can read. A directory format archive can be
153               manipulated with standard Unix tools; for example, files in an
154               uncompressed archive can be compressed with the gzip tool. This
155               format is compressed by default and also supports parallel
156               dumps.
157
158           t
159           tar
160               Output a tar-format archive suitable for input into pg_restore.
161               The tar format is compatible with the directory format:
162               extracting a tar-format archive produces a valid
163               directory-format archive. However, the tar format does not
164               support compression. Also, when using tar format the relative
165               order of table data items cannot be changed during restore.
166
167       -j njobs
168       --jobs=njobs
169           Run the dump in parallel by dumping njobs tables simultaneously.
170           This option may reduce the time needed to perform the dump but it
171           also increases the load on the database server. You can only use
172           this option with the directory output format because this is the
173           only output format where multiple processes can write their data at
174           the same time.
175
176           pg_dump will open njobs + 1 connections to the database, so make
177           sure your max_connections setting is high enough to accommodate all
178           connections.
179
180           Requesting exclusive locks on database objects while running a
181           parallel dump could cause the dump to fail. The reason is that the
182           pg_dump master process requests shared locks on the objects that
183           the worker processes are going to dump later in order to make sure
184           that nobody deletes them and makes them go away while the dump is
185           running. If another client then requests an exclusive lock on a
186           table, that lock will not be granted but will be queued waiting for
187           the shared lock of the master process to be released. Consequently
188           any other access to the table will not be granted either and will
189           queue after the exclusive lock request. This includes the worker
190           process trying to dump the table. Without any precautions this
191           would be a classic deadlock situation. To detect this conflict, the
192           pg_dump worker process requests another shared lock using the
193           NOWAIT option. If the worker process is not granted this shared
194           lock, somebody else must have requested an exclusive lock in the
195           meantime and there is no way to continue with the dump, so pg_dump
196           has no choice but to abort the dump.
197
198           For a consistent backup, the database server needs to support
199           synchronized snapshots, a feature that was introduced in PostgreSQL
200           9.2 for primary servers and 10 for standbys. With this feature,
201           database clients can ensure they see the same data set even though
202           they use different connections.  pg_dump -j uses multiple database
203           connections; it connects to the database once with the master
204           process and once again for each worker job. Without the
205           synchronized snapshot feature, the different worker jobs wouldn't
206           be guaranteed to see the same data in each connection, which could
207           lead to an inconsistent backup.
208
209           If you want to run a parallel dump of a pre-9.2 server, you need to
210           make sure that the database content doesn't change from between the
211           time the master connects to the database until the last worker job
212           has connected to the database. The easiest way to do this is to
213           halt any data modifying processes (DDL and DML) accessing the
214           database before starting the backup. You also need to specify the
215           --no-synchronized-snapshots parameter when running pg_dump -j
216           against a pre-9.2 PostgreSQL server.
217
218       -n pattern
219       --schema=pattern
220           Dump only schemas matching pattern; this selects both the schema
221           itself, and all its contained objects. When this option is not
222           specified, all non-system schemas in the target database will be
223           dumped. Multiple schemas can be selected by writing multiple -n
224           switches. The pattern parameter is interpreted as a pattern
225           according to the same rules used by psql's \d commands (see
226           Patterns below), so multiple schemas can also be selected by
227           writing wildcard characters in the pattern. When using wildcards,
228           be careful to quote the pattern if needed to prevent the shell from
229           expanding the wildcards; see Examples below.
230
231               Note
232               When -n is specified, pg_dump makes no attempt to dump any
233               other database objects that the selected schema(s) might depend
234               upon. Therefore, there is no guarantee that the results of a
235               specific-schema dump can be successfully restored by themselves
236               into a clean database.
237
238               Note
239               Non-schema objects such as blobs are not dumped when -n is
240               specified. You can add blobs back to the dump with the --blobs
241               switch.
242
243       -N pattern
244       --exclude-schema=pattern
245           Do not dump any schemas matching pattern. The pattern is
246           interpreted according to the same rules as for -n.  -N can be given
247           more than once to exclude schemas matching any of several patterns.
248
249           When both -n and -N are given, the behavior is to dump just the
250           schemas that match at least one -n switch but no -N switches. If -N
251           appears without -n, then schemas matching -N are excluded from what
252           is otherwise a normal dump.
253
254       -O
255       --no-owner
256           Do not output commands to set ownership of objects to match the
257           original database. By default, pg_dump issues ALTER OWNER or SET
258           SESSION AUTHORIZATION statements to set ownership of created
259           database objects. These statements will fail when the script is run
260           unless it is started by a superuser (or the same user that owns all
261           of the objects in the script). To make a script that can be
262           restored by any user, but will give that user ownership of all the
263           objects, specify -O.
264
265           This option is ignored when emitting an archive (non-text) output
266           file. For the archive formats, you can specify the option when you
267           call pg_restore.
268
269       -R
270       --no-reconnect
271           This option is obsolete but still accepted for backwards
272           compatibility.
273
274       -s
275       --schema-only
276           Dump only the object definitions (schema), not data.
277
278           This option is the inverse of --data-only. It is similar to, but
279           for historical reasons not identical to, specifying
280           --section=pre-data --section=post-data.
281
282           (Do not confuse this with the --schema option, which uses the word
283           “schema” in a different meaning.)
284
285           To exclude table data for only a subset of tables in the database,
286           see --exclude-table-data.
287
288       -S username
289       --superuser=username
290           Specify the superuser user name to use when disabling triggers.
291           This is relevant only if --disable-triggers is used. (Usually, it's
292           better to leave this out, and instead start the resulting script as
293           superuser.)
294
295       -t pattern
296       --table=pattern
297           Dump only tables with names matching pattern. Multiple tables can
298           be selected by writing multiple -t switches. The pattern parameter
299           is interpreted as a pattern according to the same rules used by
300           psql's \d commands (see Patterns below), so multiple tables can
301           also be selected by writing wildcard characters in the pattern.
302           When using wildcards, be careful to quote the pattern if needed to
303           prevent the shell from expanding the wildcards; see Examples below.
304
305           As well as tables, this option can be used to dump the definition
306           of matching views, materialized views, foreign tables, and
307           sequences. It will not dump the contents of views or materialized
308           views, and the contents of foreign tables will only be dumped if
309           the corresponding foreign server is specified with
310           --include-foreign-data.
311
312           The -n and -N switches have no effect when -t is used, because
313           tables selected by -t will be dumped regardless of those switches,
314           and non-table objects will not be dumped.
315
316               Note
317               When -t is specified, pg_dump makes no attempt to dump any
318               other database objects that the selected table(s) might depend
319               upon. Therefore, there is no guarantee that the results of a
320               specific-table dump can be successfully restored by themselves
321               into a clean database.
322
323               Note
324               The behavior of the -t switch is not entirely upward compatible
325               with pre-8.2 PostgreSQL versions. Formerly, writing -t tab
326               would dump all tables named tab, but now it just dumps
327               whichever one is visible in your default search path. To get
328               the old behavior you can write -t '*.tab'. Also, you must write
329               something like -t sch.tab to select a table in a particular
330               schema, rather than the old locution of -n sch -t tab.
331
332       -T pattern
333       --exclude-table=pattern
334           Do not dump any tables matching pattern. The pattern is interpreted
335           according to the same rules as for -t.  -T can be given more than
336           once to exclude tables matching any of several patterns.
337
338           When both -t and -T are given, the behavior is to dump just the
339           tables that match at least one -t switch but no -T switches. If -T
340           appears without -t, then tables matching -T are excluded from what
341           is otherwise a normal dump.
342
343       -v
344       --verbose
345           Specifies verbose mode. This will cause pg_dump to output detailed
346           object comments and start/stop times to the dump file, and progress
347           messages to standard error.
348
349       -V
350       --version
351           Print the pg_dump version and exit.
352
353       -x
354       --no-privileges
355       --no-acl
356           Prevent dumping of access privileges (grant/revoke commands).
357
358       -Z 0..9
359       --compress=0..9
360           Specify the compression level to use. Zero means no compression.
361           For the custom and directory archive formats, this specifies
362           compression of individual table-data segments, and the default is
363           to compress at a moderate level. For plain text output, setting a
364           nonzero compression level causes the entire output file to be
365           compressed, as though it had been fed through gzip; but the default
366           is not to compress. The tar archive format currently does not
367           support compression at all.
368
369       --binary-upgrade
370           This option is for use by in-place upgrade utilities. Its use for
371           other purposes is not recommended or supported. The behavior of the
372           option may change in future releases without notice.
373
374       --column-inserts
375       --attribute-inserts
376           Dump data as INSERT commands with explicit column names (INSERT
377           INTO table (column, ...) VALUES ...). This will make restoration
378           very slow; it is mainly useful for making dumps that can be loaded
379           into non-PostgreSQL databases. Any error during reloading will
380           cause only rows that are part of the problematic INSERT to be lost,
381           rather than the entire table contents.
382
383       --disable-dollar-quoting
384           This option disables the use of dollar quoting for function bodies,
385           and forces them to be quoted using SQL standard string syntax.
386
387       --disable-triggers
388           This option is relevant only when creating a data-only dump. It
389           instructs pg_dump to include commands to temporarily disable
390           triggers on the target tables while the data is reloaded. Use this
391           if you have referential integrity checks or other triggers on the
392           tables that you do not want to invoke during data reload.
393
394           Presently, the commands emitted for --disable-triggers must be done
395           as superuser. So, you should also specify a superuser name with -S,
396           or preferably be careful to start the resulting script as a
397           superuser.
398
399           This option is ignored when emitting an archive (non-text) output
400           file. For the archive formats, you can specify the option when you
401           call pg_restore.
402
403       --enable-row-security
404           This option is relevant only when dumping the contents of a table
405           which has row security. By default, pg_dump will set row_security
406           to off, to ensure that all data is dumped from the table. If the
407           user does not have sufficient privileges to bypass row security,
408           then an error is thrown. This parameter instructs pg_dump to set
409           row_security to on instead, allowing the user to dump the parts of
410           the contents of the table that they have access to.
411
412           Note that if you use this option currently, you probably also want
413           the dump be in INSERT format, as the COPY FROM during restore does
414           not support row security.
415
416       --exclude-table-data=pattern
417           Do not dump data for any tables matching pattern. The pattern is
418           interpreted according to the same rules as for -t.
419           --exclude-table-data can be given more than once to exclude tables
420           matching any of several patterns. This option is useful when you
421           need the definition of a particular table even though you do not
422           need the data in it.
423
424           To exclude data for all tables in the database, see --schema-only.
425
426       --extra-float-digits=ndigits
427           Use the specified value of extra_float_digits when dumping
428           floating-point data, instead of the maximum available precision.
429           Routine dumps made for backup purposes should not use this option.
430
431       --if-exists
432           Use conditional commands (i.e., add an IF EXISTS clause) when
433           cleaning database objects. This option is not valid unless --clean
434           is also specified.
435
436       --include-foreign-data=foreignserver
437           Dump the data for any foreign table with a foreign server matching
438           foreignserver pattern. Multiple foreign servers can be selected by
439           writing multiple --include-foreign-data switches. Also, the
440           foreignserver parameter is interpreted as a pattern according to
441           the same rules used by psql's \d commands (see Patterns below), so
442           multiple foreign servers can also be selected by writing wildcard
443           characters in the pattern. When using wildcards, be careful to
444           quote the pattern if needed to prevent the shell from expanding the
445           wildcards; see Examples below. The only exception is that an empty
446           pattern is disallowed.
447
448               Note
449               When --include-foreign-data is specified, pg_dump does not
450               check that the foreign table is writable. Therefore, there is
451               no guarantee that the results of a foreign table dump can be
452               successfully restored.
453
454       --inserts
455           Dump data as INSERT commands (rather than COPY). This will make
456           restoration very slow; it is mainly useful for making dumps that
457           can be loaded into non-PostgreSQL databases. Any error during
458           reloading will cause only rows that are part of the problematic
459           INSERT to be lost, rather than the entire table contents. Note that
460           the restore might fail altogether if you have rearranged column
461           order. The --column-inserts option is safe against column order
462           changes, though even slower.
463
464       --load-via-partition-root
465           When dumping data for a table partition, make the COPY or INSERT
466           statements target the root of the partitioning hierarchy that
467           contains it, rather than the partition itself. This causes the
468           appropriate partition to be re-determined for each row when the
469           data is loaded. This may be useful when reloading data on a server
470           where rows do not always fall into the same partitions as they did
471           on the original server. That could happen, for example, if the
472           partitioning column is of type text and the two systems have
473           different definitions of the collation used to sort the
474           partitioning column.
475
476           It is best not to use parallelism when restoring from an archive
477           made with this option, because pg_restore will not know exactly
478           which partition(s) a given archive data item will load data into.
479           This could result in inefficiency due to lock conflicts between
480           parallel jobs, or perhaps even reload failures due to foreign key
481           constraints being set up before all the relevant data is loaded.
482
483       --lock-wait-timeout=timeout
484           Do not wait forever to acquire shared table locks at the beginning
485           of the dump. Instead fail if unable to lock a table within the
486           specified timeout. The timeout may be specified in any of the
487           formats accepted by SET statement_timeout. (Allowed formats vary
488           depending on the server version you are dumping from, but an
489           integer number of milliseconds is accepted by all versions.)
490
491       --no-comments
492           Do not dump comments.
493
494       --no-publications
495           Do not dump publications.
496
497       --no-security-labels
498           Do not dump security labels.
499
500       --no-subscriptions
501           Do not dump subscriptions.
502
503       --no-sync
504           By default, pg_dump will wait for all files to be written safely to
505           disk. This option causes pg_dump to return without waiting, which
506           is faster, but means that a subsequent operating system crash can
507           leave the dump corrupt. Generally, this option is useful for
508           testing but should not be used when dumping data from production
509           installation.
510
511       --no-synchronized-snapshots
512           This option allows running pg_dump -j against a pre-9.2 server, see
513           the documentation of the -j parameter for more details.
514
515       --no-tablespaces
516           Do not output commands to select tablespaces. With this option, all
517           objects will be created in whichever tablespace is the default
518           during restore.
519
520           This option is ignored when emitting an archive (non-text) output
521           file. For the archive formats, you can specify the option when you
522           call pg_restore.
523
524       --no-unlogged-table-data
525           Do not dump the contents of unlogged tables. This option has no
526           effect on whether or not the table definitions (schema) are dumped;
527           it only suppresses dumping the table data. Data in unlogged tables
528           is always excluded when dumping from a standby server.
529
530       --on-conflict-do-nothing
531           Add ON CONFLICT DO NOTHING to INSERT commands. This option is not
532           valid unless --inserts, --column-inserts or --rows-per-insert is
533           also specified.
534
535       --quote-all-identifiers
536           Force quoting of all identifiers. This option is recommended when
537           dumping a database from a server whose PostgreSQL major version is
538           different from pg_dump's, or when the output is intended to be
539           loaded into a server of a different major version. By default,
540           pg_dump quotes only identifiers that are reserved words in its own
541           major version. This sometimes results in compatibility issues when
542           dealing with servers of other versions that may have slightly
543           different sets of reserved words. Using --quote-all-identifiers
544           prevents such issues, at the price of a harder-to-read dump script.
545
546       --rows-per-insert=nrows
547           Dump data as INSERT commands (rather than COPY). Controls the
548           maximum number of rows per INSERT command. The value specified must
549           be a number greater than zero. Any error during reloading will
550           cause only rows that are part of the problematic INSERT to be lost,
551           rather than the entire table contents.
552
553       --section=sectionname
554           Only dump the named section. The section name can be pre-data,
555           data, or post-data. This option can be specified more than once to
556           select multiple sections. The default is to dump all sections.
557
558           The data section contains actual table data, large-object contents,
559           and sequence values. Post-data items include definitions of
560           indexes, triggers, rules, and constraints other than validated
561           check constraints. Pre-data items include all other data definition
562           items.
563
564       --serializable-deferrable
565           Use a serializable transaction for the dump, to ensure that the
566           snapshot used is consistent with later database states; but do this
567           by waiting for a point in the transaction stream at which no
568           anomalies can be present, so that there isn't a risk of the dump
569           failing or causing other transactions to roll back with a
570           serialization_failure. See Chapter 13 for more information about
571           transaction isolation and concurrency control.
572
573           This option is not beneficial for a dump which is intended only for
574           disaster recovery. It could be useful for a dump used to load a
575           copy of the database for reporting or other read-only load sharing
576           while the original database continues to be updated. Without it the
577           dump may reflect a state which is not consistent with any serial
578           execution of the transactions eventually committed. For example, if
579           batch processing techniques are used, a batch may show as closed in
580           the dump without all of the items which are in the batch appearing.
581
582           This option will make no difference if there are no read-write
583           transactions active when pg_dump is started. If read-write
584           transactions are active, the start of the dump may be delayed for
585           an indeterminate length of time. Once running, performance with or
586           without the switch is the same.
587
588       --snapshot=snapshotname
589           Use the specified synchronized snapshot when making a dump of the
590           database (see Table 9.88 for more details).
591
592           This option is useful when needing to synchronize the dump with a
593           logical replication slot (see Chapter 48) or with a concurrent
594           session.
595
596           In the case of a parallel dump, the snapshot name defined by this
597           option is used rather than taking a new snapshot.
598
599       --strict-names
600           Require that each schema (-n/--schema) and table (-t/--table)
601           qualifier match at least one schema/table in the database to be
602           dumped. Note that if none of the schema/table qualifiers find
603           matches, pg_dump will generate an error even without
604           --strict-names.
605
606           This option has no effect on -N/--exclude-schema,
607           -T/--exclude-table, or --exclude-table-data. An exclude pattern
608           failing to match any objects is not considered an error.
609
610       --use-set-session-authorization
611           Output SQL-standard SET SESSION AUTHORIZATION commands instead of
612           ALTER OWNER commands to determine object ownership. This makes the
613           dump more standards-compatible, but depending on the history of the
614           objects in the dump, might not restore properly. Also, a dump using
615           SET SESSION AUTHORIZATION will certainly require superuser
616           privileges to restore correctly, whereas ALTER OWNER requires
617           lesser privileges.
618
619       -?
620       --help
621           Show help about pg_dump command line arguments, and exit.
622
623       The following command-line options control the database connection
624       parameters.
625
626       -d dbname
627       --dbname=dbname
628           Specifies the name of the database to connect to. This is
629           equivalent to specifying dbname as the first non-option argument on
630           the command line. The dbname can be a connection string. If so,
631           connection string parameters will override any conflicting command
632           line options.
633
634       -h host
635       --host=host
636           Specifies the host name of the machine on which the server is
637           running. If the value begins with a slash, it is used as the
638           directory for the Unix domain socket. The default is taken from the
639           PGHOST environment variable, if set, else a Unix domain socket
640           connection is attempted.
641
642       -p port
643       --port=port
644           Specifies the TCP port or local Unix domain socket file extension
645           on which the server is listening for connections. Defaults to the
646           PGPORT environment variable, if set, or a compiled-in default.
647
648       -U username
649       --username=username
650           User name to connect as.
651
652       -w
653       --no-password
654           Never issue a password prompt. If the server requires password
655           authentication and a password is not available by other means such
656           as a .pgpass file, the connection attempt will fail. This option
657           can be useful in batch jobs and scripts where no user is present to
658           enter a password.
659
660       -W
661       --password
662           Force pg_dump to prompt for a password before connecting to a
663           database.
664
665           This option is never essential, since pg_dump will automatically
666           prompt for a password if the server demands password
667           authentication. However, pg_dump will waste a connection attempt
668           finding out that the server wants a password. In some cases it is
669           worth typing -W to avoid the extra connection attempt.
670
671       --role=rolename
672           Specifies a role name to be used to create the dump. This option
673           causes pg_dump to issue a SET ROLE rolename command after
674           connecting to the database. It is useful when the authenticated
675           user (specified by -U) lacks privileges needed by pg_dump, but can
676           switch to a role with the required rights. Some installations have
677           a policy against logging in directly as a superuser, and use of
678           this option allows dumps to be made without violating the policy.
679

ENVIRONMENT

681       PGDATABASE
682       PGHOST
683       PGOPTIONS
684       PGPORT
685       PGUSER
686           Default connection parameters.
687
688       PG_COLOR
689           Specifies whether to use color in diagnostic messages. Possible
690           values are always, auto and never.
691
692       This utility, like most other PostgreSQL utilities, also uses the
693       environment variables supported by libpq (see Section 33.14).
694

DIAGNOSTICS

696       pg_dump internally executes SELECT statements. If you have problems
697       running pg_dump, make sure you are able to select information from the
698       database using, for example, psql(1). Also, any default connection
699       settings and environment variables used by the libpq front-end library
700       will apply.
701
702       The database activity of pg_dump is normally collected by the
703       statistics collector. If this is undesirable, you can set parameter
704       track_counts to false via PGOPTIONS or the ALTER USER command.
705

NOTES

707       If your database cluster has any local additions to the template1
708       database, be careful to restore the output of pg_dump into a truly
709       empty database; otherwise you are likely to get errors due to duplicate
710       definitions of the added objects. To make an empty database without any
711       local additions, copy from template0 not template1, for example:
712
713           CREATE DATABASE foo WITH TEMPLATE template0;
714
715       When a data-only dump is chosen and the option --disable-triggers is
716       used, pg_dump emits commands to disable triggers on user tables before
717       inserting the data, and then commands to re-enable them after the data
718       has been inserted. If the restore is stopped in the middle, the system
719       catalogs might be left in the wrong state.
720
721       The dump file produced by pg_dump does not contain the statistics used
722       by the optimizer to make query planning decisions. Therefore, it is
723       wise to run ANALYZE after restoring from a dump file to ensure optimal
724       performance; see Section 24.1.3 and Section 24.1.6 for more
725       information.
726
727       Because pg_dump is used to transfer data to newer versions of
728       PostgreSQL, the output of pg_dump can be expected to load into
729       PostgreSQL server versions newer than pg_dump's version.  pg_dump can
730       also dump from PostgreSQL servers older than its own version.
731       (Currently, servers back to version 8.0 are supported.) However,
732       pg_dump cannot dump from PostgreSQL servers newer than its own major
733       version; it will refuse to even try, rather than risk making an invalid
734       dump. Also, it is not guaranteed that pg_dump's output can be loaded
735       into a server of an older major version — not even if the dump was
736       taken from a server of that version. Loading a dump file into an older
737       server may require manual editing of the dump file to remove syntax not
738       understood by the older server. Use of the --quote-all-identifiers
739       option is recommended in cross-version cases, as it can prevent
740       problems arising from varying reserved-word lists in different
741       PostgreSQL versions.
742
743       When dumping logical replication subscriptions, pg_dump will generate
744       CREATE SUBSCRIPTION commands that use the connect = false option, so
745       that restoring the subscription does not make remote connections for
746       creating a replication slot or for initial table copy. That way, the
747       dump can be restored without requiring network access to the remote
748       servers. It is then up to the user to reactivate the subscriptions in a
749       suitable way. If the involved hosts have changed, the connection
750       information might have to be changed. It might also be appropriate to
751       truncate the target tables before initiating a new full table copy.
752

EXAMPLES

754       To dump a database called mydb into a SQL-script file:
755
756           $ pg_dump mydb > db.sql
757
758       To reload such a script into a (freshly created) database named newdb:
759
760           $ psql -d newdb -f db.sql
761
762       To dump a database into a custom-format archive file:
763
764           $ pg_dump -Fc mydb > db.dump
765
766       To dump a database into a directory-format archive:
767
768           $ pg_dump -Fd mydb -f dumpdir
769
770       To dump a database into a directory-format archive in parallel with 5
771       worker jobs:
772
773           $ pg_dump -Fd mydb -j 5 -f dumpdir
774
775       To reload an archive file into a (freshly created) database named
776       newdb:
777
778           $ pg_restore -d newdb db.dump
779
780       To reload an archive file into the same database it was dumped from,
781       discarding the current contents of that database:
782
783           $ pg_restore -d postgres --clean --create db.dump
784
785       To dump a single table named mytab:
786
787           $ pg_dump -t mytab mydb > db.sql
788
789       To dump all tables whose names start with emp in the detroit schema,
790       except for the table named employee_log:
791
792           $ pg_dump -t 'detroit.emp*' -T detroit.employee_log mydb > db.sql
793
794       To dump all schemas whose names start with east or west and end in gsm,
795       excluding any schemas whose names contain the word test:
796
797           $ pg_dump -n 'east*gsm' -n 'west*gsm' -N '*test*' mydb > db.sql
798
799       The same, using regular expression notation to consolidate the
800       switches:
801
802           $ pg_dump -n '(east|west)*gsm' -N '*test*' mydb > db.sql
803
804       To dump all database objects except for tables whose names begin with
805       ts_:
806
807           $ pg_dump -T 'ts_*' mydb > db.sql
808
809       To specify an upper-case or mixed-case name in -t and related switches,
810       you need to double-quote the name; else it will be folded to lower case
811       (see Patterns below). But double quotes are special to the shell, so in
812       turn they must be quoted. Thus, to dump a single table with a
813       mixed-case name, you need something like
814
815           $ pg_dump -t "\"MixedCaseName\"" mydb > mytab.sql
816

SEE ALSO

818       pg_dumpall(1), pg_restore(1), psql(1)
819
820
821
822PostgreSQL 13.3                      2021                           PG_DUMP(1)
Impressum