4 pg_dumpall — extract a PostgreSQL database cluster into a script file
8 pg_dumpall [connection-option...] [option...]
12 pg_dumpall is a utility for writing out (“dumping”) all PostgreSQL
13 databases of a cluster into one script file. The script file contains
14 SQL commands that can be used as input to psql to restore the
15 databases. It does this by calling pg_dump for each database in the
16 cluster. pg_dumpall also dumps global objects that are common to all
17 databases, namely database roles, tablespaces, and privilege grants for
18 configuration parameters. (pg_dump does not save these objects.)
20 Since pg_dumpall reads tables from all databases you will most likely
21 have to connect as a database superuser in order to produce a complete
22 dump. Also you will need superuser privileges to execute the saved
23 script in order to be allowed to add roles and create databases.
25 The SQL script will be written to the standard output. Use the
26 -f/--file option or shell operators to redirect it into a file.
28 pg_dumpall needs to connect several times to the PostgreSQL server
29 (once per database). If you use password authentication it will ask for
30 a password each time. It is convenient to have a ~/.pgpass file in such
31 cases. See Section 32.16 for more information.
35 Restoring a dump causes the destination to execute arbitrary code of
36 the source superusers' choice. Partial dumps and partial restores do
37 not limit that. If the source superusers are not trusted, the dumped
38 SQL statements must be inspected before restoring. Note that the client
39 running the dump and restore need not trust the source or destination
44 The following command-line options control the content and format of
49 Dump only the data, not the schema (data definitions) or
54 Emit SQL commands to DROP all the dumped databases, roles, and
55 tablespaces before recreating them. This option is useful when
56 the restore is to overwrite an existing cluster. If any of the
57 objects do not exist in the destination cluster, ignorable error
58 messages will be reported during restore, unless --if-exists is
63 Create the dump in the specified character set encoding. By
64 default, the dump is created in the database encoding. (Another
65 way to get the same result is to set the PGCLIENTENCODING
66 environment variable to the desired dump encoding.)
70 Send output to the specified file. If this is omitted, the
71 standard output is used.
75 Dump only global objects (roles and tablespaces), no databases.
79 Do not output commands to set ownership of objects to match the
80 original database. By default, pg_dumpall issues ALTER OWNER or
81 SET SESSION AUTHORIZATION statements to set ownership of created
82 schema elements. These statements will fail when the script is
83 run unless it is started by a superuser (or the same user that
84 owns all of the objects in the script). To make a script that
85 can be restored by any user, but will give that user ownership
86 of all the objects, specify -O.
90 Dump only roles, no databases or tablespaces.
94 Dump only the object definitions (schema), not data.
98 Specify the superuser user name to use when disabling triggers.
99 This is relevant only if --disable-triggers is used. (Usually,
100 it's better to leave this out, and instead start the resulting
101 script as superuser.)
105 Dump only tablespaces, no databases or roles.
109 Specifies verbose mode. This will cause pg_dumpall to output
110 start/stop times to the dump file, and progress messages to
111 standard error. Repeating the option causes additional
112 debug-level messages to appear on standard error. The option is
113 also passed down to pg_dump.
117 Print the pg_dumpall version and exit.
122 Prevent dumping of access privileges (grant/revoke commands).
125 This option is for use by in-place upgrade utilities. Its use
126 for other purposes is not recommended or supported. The behavior
127 of the option may change in future releases without notice.
131 Dump data as INSERT commands with explicit column names (INSERT
132 INTO table (column, ...) VALUES ...). This will make restoration
133 very slow; it is mainly useful for making dumps that can be
134 loaded into non-PostgreSQL databases.
136 --disable-dollar-quoting
137 This option disables the use of dollar quoting for function
138 bodies, and forces them to be quoted using SQL standard string
142 This option is relevant only when creating a dump with data and
143 without schema. It instructs pg_dumpall to include commands to
144 temporarily disable triggers on the target tables while the data
145 is restored. Use this if you have referential integrity checks
146 or other triggers on the tables that you do not want to invoke
149 Presently, the commands emitted for --disable-triggers must be
150 done as superuser. So, you should also specify a superuser name
151 with -S, or preferably be careful to start the resulting script
154 --exclude-database=pattern
155 Do not dump databases whose name matches pattern. Multiple
156 patterns can be excluded by writing multiple --exclude-database
157 switches. The pattern parameter is interpreted as a pattern
158 according to the same rules used by psql's \d commands (see
159 Patterns), so multiple databases can also be excluded by writing
160 wildcard characters in the pattern. When using wildcards, be
161 careful to quote the pattern if needed to prevent shell wildcard
164 --extra-float-digits=ndigits
165 Use the specified value of extra_float_digits when dumping
166 floating-point data, instead of the maximum available precision.
167 Routine dumps made for backup purposes should not use this
171 Specify a filename from which to read patterns for databases
172 excluded from the dump. The patterns are interpreted according
173 to the same rules as --exclude-database. To read from STDIN, use
174 - as the filename. The --filter option can be specified in
175 conjunction with --exclude-database for excluding databases, and
176 can also be specified more than once for multiple filter files.
178 The file lists one database pattern per row, with the following
181 exclude database PATTERN
183 Lines starting with # are considered comments and ignored.
184 Comments can be placed after an object pattern row as well.
185 Blank lines are also ignored. See Patterns for how to perform
189 Use DROP ... IF EXISTS commands to drop objects in --clean mode.
190 This suppresses “does not exist” errors that might otherwise be
191 reported. This option is not valid unless --clean is also
195 Dump data as INSERT commands (rather than COPY). This will make
196 restoration very slow; it is mainly useful for making dumps that
197 can be loaded into non-PostgreSQL databases. Note that the
198 restore might fail altogether if you have rearranged column
199 order. The --column-inserts option is safer, though even slower.
201 --load-via-partition-root
202 When dumping data for a table partition, make the COPY or INSERT
203 statements target the root of the partitioning hierarchy that
204 contains it, rather than the partition itself. This causes the
205 appropriate partition to be re-determined for each row when the
206 data is loaded. This may be useful when restoring data on a
207 server where rows do not always fall into the same partitions as
208 they did on the original server. That could happen, for example,
209 if the partitioning column is of type text and the two systems
210 have different definitions of the collation used to sort the
213 --lock-wait-timeout=timeout
214 Do not wait forever to acquire shared table locks at the
215 beginning of the dump. Instead, fail if unable to lock a table
216 within the specified timeout. The timeout may be specified in
217 any of the formats accepted by SET statement_timeout.
220 Do not dump COMMENT commands.
226 Do not dump row security policies.
229 Do not dump publications.
232 Do not dump passwords for roles. When restored, roles will have
233 a null password, and password authentication will always fail
234 until the password is set. Since password values aren't needed
235 when this option is specified, the role information is read from
236 the catalog view pg_roles instead of pg_authid. Therefore, this
237 option also helps if access to pg_authid is restricted by some
241 Do not dump schema (data definitions).
244 Do not dump security labels.
247 Do not dump statistics. This is the default.
250 Do not dump subscriptions.
253 By default, pg_dumpall will wait for all files to be written
254 safely to disk. This option causes pg_dumpall to return without
255 waiting, which is faster, but means that a subsequent operating
256 system crash can leave the dump corrupt. Generally, this option
257 is useful for testing but should not be used when dumping data
258 from production installation.
260 --no-table-access-method
261 Do not output commands to select table access methods. With this
262 option, all objects will be created with whichever table access
263 method is the default during restore.
266 Do not output commands to create tablespaces nor select
267 tablespaces for objects. With this option, all objects will be
268 created in whichever tablespace is the default during restore.
270 --no-toast-compression
271 Do not output commands to set TOAST compression methods. With
272 this option, all columns will be restored with the default
275 --no-unlogged-table-data
276 Do not dump the contents of unlogged tables. This option has no
277 effect on whether or not the table definitions (schema) are
278 dumped; it only suppresses dumping the table data.
280 --on-conflict-do-nothing
281 Add ON CONFLICT DO NOTHING to INSERT commands. This option is
282 not valid unless --inserts or --column-inserts is also
285 --quote-all-identifiers
286 Force quoting of all identifiers. This option is recommended
287 when dumping a database from a server whose PostgreSQL major
288 version is different from pg_dumpall's, or when the output is
289 intended to be loaded into a server of a different major
290 version. By default, pg_dumpall quotes only identifiers that are
291 reserved words in its own major version. This sometimes results
292 in compatibility issues when dealing with servers of other
293 versions that may have slightly different sets of reserved
294 words. Using --quote-all-identifiers prevents such issues, at
295 the price of a harder-to-read dump script.
297 --restrict-key=restrict_key
298 Use the provided string as the psql \restrict key in the dump
299 output. If no restrict key is specified, pg_dumpall will
300 generate a random one as needed. Keys may contain only
301 alphanumeric characters.
303 This option is primarily intended for testing purposes and other
304 scenarios that require repeatable output (e.g., comparing dump
305 files). It is not recommended for general use, as a malicious
306 server with advance knowledge of the key may be able to inject
307 arbitrary code that will be executed on the machine that runs
308 psql with the dump output.
310 --rows-per-insert=nrows
311 Dump data as INSERT commands (rather than COPY). Controls the
312 maximum number of rows per INSERT command. The value specified
313 must be a number greater than zero. Any error during restoring
314 will cause only rows that are part of the problematic INSERT to
315 be lost, rather than the entire table contents.
321 Dump only the statistics, not the schema (data definitions) or
322 data. Statistics for tables, materialized views, foreign tables,
323 and indexes are dumped.
326 Include sequence data in the dump. This is the default behavior
327 except when --no-data, --schema-only, or --statistics-only is
330 --use-set-session-authorization
331 Output SQL-standard SET SESSION AUTHORIZATION commands instead
332 of ALTER OWNER commands to determine object ownership. This
333 makes the dump more standards compatible, but depending on the
334 history of the objects in the dump, might not restore properly.
338 Show help about pg_dumpall command line arguments, and exit.
340 The following command-line options control the database connection
345 Specifies parameters used to connect to the server, as a
346 connection string; these will override any conflicting command
349 The option is called --dbname for consistency with other client
350 applications, but because pg_dumpall needs to connect to many
351 databases, the database name in the connection string will be
352 ignored. Use the -l option to specify the name of the database
353 used for the initial connection, which will dump global objects
354 and discover what other databases should be dumped.
358 Specifies the host name of the machine on which the database
359 server is running. If the value begins with a slash, it is used
360 as the directory for the Unix domain socket. The default is
361 taken from the PGHOST environment variable, if set, else a Unix
362 domain socket connection is attempted.
366 Specifies the name of the database to connect to for dumping
367 global objects and discovering what other databases should be
368 dumped. If not specified, the postgres database will be used,
369 and if that does not exist, template1 will be used.
373 Specifies the TCP port or local Unix domain socket file
374 extension on which the server is listening for connections.
375 Defaults to the PGPORT environment variable, if set, or a
380 User name to connect as.
384 Never issue a password prompt. If the server requires password
385 authentication and a password is not available by other means
386 such as a .pgpass file, the connection attempt will fail. This
387 option can be useful in batch jobs and scripts where no user is
388 present to enter a password.
392 Force pg_dumpall to prompt for a password before connecting to a
395 This option is never essential, since pg_dumpall will
396 automatically prompt for a password if the server demands
397 password authentication. However, pg_dumpall will waste a
398 connection attempt finding out that the server wants a password.
399 In some cases it is worth typing -W to avoid the extra
402 Note that the password prompt will occur again for each database
403 to be dumped. Usually, it's better to set up a ~/.pgpass file
404 than to rely on manual password entry.
407 Specifies a role name to be used to create the dump. This option
408 causes pg_dumpall to issue a SET ROLE rolename command after
409 connecting to the database. It is useful when the authenticated
410 user (specified by -U) lacks privileges needed by pg_dumpall,
411 but can switch to a role with the required rights. Some
412 installations have a policy against logging in directly as a
413 superuser, and use of this option allows dumps to be made
414 without violating the policy.
422 Default connection parameters
425 Specifies whether to use color in diagnostic messages. Possible
426 values are always, auto and never.
428 This utility, like most other PostgreSQL utilities, also uses the
429 environment variables supported by libpq (see Section 32.15).
433 Since pg_dumpall calls pg_dump internally, some diagnostic messages
434 will refer to pg_dump.
436 The --clean option can be useful even when your intention is to restore
437 the dump script into a fresh cluster. Use of --clean authorizes the
438 script to drop and re-create the built-in postgres and template1
439 databases, ensuring that those databases will retain the same
440 properties (for instance, locale and encoding) that they had in the
441 source cluster. Without the option, those databases will retain their
442 existing database-level properties, as well as any pre-existing
445 If --statistics is specified, pg_dumpall will include most optimizer
446 statistics in the resulting dump file. However, some statistics may not
447 be included, such as those created explicitly with CREATE STATISTICS or
448 custom statistics added by an extension. Therefore, it may be useful to
449 run ANALYZE on each database after restoring from a dump file to ensure
450 optimal performance. You can also run vacuumdb -a -z to analyze all
453 The dump script should not be expected to run completely without
454 errors. In particular, because the script will issue CREATE ROLE for
455 every role existing in the source cluster, it is certain to get a “role
456 already exists” error for the bootstrap superuser, unless the
457 destination cluster was initialized with a different bootstrap
458 superuser name. This error is harmless and should be ignored. Use of
459 the --clean option is likely to produce additional harmless error
460 messages about non-existent objects, although you can minimize those by
463 pg_dumpall requires all needed tablespace directories to exist before
464 the restore; otherwise, database creation will fail for databases in
465 non-default locations.
467 It is generally recommended to use the -X (--no-psqlrc) option when
468 restoring a database from a pg_dumpall script to ensure a clean restore
469 process and prevent potential conflicts with non-default psql
470 configurations. Additionally, because the pg_dumpall script may include
471 psql meta-commands, it may be incompatible with clients other than
476 To dump all databases:
477 $ pg_dumpall > db.out
479 To restore database(s) from this file, you can use:
480 $ psql -X -f db.out -d postgres
482 It is not important which database you connect to here since the script
483 file created by pg_dumpall will contain the appropriate commands to
484 create and connect to the saved databases. An exception is that if you
485 specified --clean, you must connect to the postgres database initially;
486 the script will attempt to drop other databases immediately, and that
487 will fail for the database you are connected to.
491 Check pg_dump for details on possible error conditions.