aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/pg_dump.sgml
blob: c6041237240204fe560e20c91e8eb6481ab3942d (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/pg_dump.sgml,v 1.68 2003/12/01 22:07:58 momjian Exp $
PostgreSQL documentation
-->

<refentry id="APP-PGDUMP">
 <refmeta>
  <refentrytitle>pg_dump</refentrytitle>
  <manvolnum>1</manvolnum>
  <refmiscinfo>Application</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>pg_dump</refname>

  <refpurpose>
   extract a <productname>PostgreSQL</productname> database into a script file or other archive file 
  </refpurpose>
 </refnamediv>

 <indexterm zone="app-pgdump">
  <primary>pg_dump</primary>
 </indexterm>

 <refsynopsisdiv>
  <cmdsynopsis>
   <command>pg_dump</command>
   <arg rep="repeat"><replaceable>option</replaceable></arg>
   <arg><replaceable>dbname</replaceable></arg>
  </cmdsynopsis>
 </refsynopsisdiv>


 <refsect1 id="pg-dump-description">
  <title>
   Description
  </title>

  <para>
   <application>pg_dump</application> is a utility for backing up a
   <productname>PostgreSQL</productname> database. It makes consistent
   backups even if the database is being used concurrently.
   <application>pg_dump</application> does not block other users
   accessing the database (readers or writers).
  </para>

  <para>
   Dumps can be output in script or archive file formats. The script
   files are in plain-text format and contain the SQL commands required
   to reconstruct the database to the state it was in at the time it was
   saved. To restore these scripts, use <xref linkend="app-psql">. They
   can be used to reconstruct the database even on other machines and
   other architectures, with some modifications even on other SQL
   database products.
  </para>

  <para>
   The alternative archive file formats that are meant to be used with
   <xref linkend="app-pgrestore"> to rebuild the database, and they also
   allow <application>pg_restore</application> to be selective about
   what is restored, or even to reorder the items prior to being
   restored. The archive files are also designed to be portable across
   architectures.
  </para>

  <para>
   When used with one of the archive file formats and combined with
   <application>pg_restore</application>,
   <application>pg_dump</application> provides a flexible archival and
   transfer mechanism. <application>pg_dump</application> can be used to
   backup an entire database, then <application>pg_restore</application>
   can be used to examine the archive and/or select which parts of the
   database are to be restored. The most flexible output file format is
   the <quote>custom</quote> format (<option>-Fc</option>). It allows
   for selection and reordering of all archived items, and is compressed
   by default. The <application>tar</application> format
   (<option>-Ft</option>) is not compressed and it is not possible to
   reorder data when loading, but it is otherwise quite flexible;
   moreover, it can be manipulated with other tools such as
   <command>tar</command>.
  </para>

  <para>
   While running <application>pg_dump</application>, one should examine the
   output for any warnings (printed on standard error), especially in
   light of the limitations listed below.
  </para>

 </refsect1>

 <refsect1 id="pg-dump-options">
  <title>Options</title>

  <para>
   The following command-line options are used to control the output format.

    <variablelist>
     <varlistentry>
      <term><replaceable class="parameter">dbname</replaceable></term>
      <listitem>
       <para>
	Specifies the name of the database to be dumped.  If this is
	not specified, the environment variable
	<envar>PGDATABASE</envar> is used.  If that is not set, the
	user name specified for the connection is used.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-a</></term>
      <term><option>--data-only</></term>
      <listitem>
       <para>
	Dump only the data, not the schema (data definitions).
       </para>

       <para>
        This option is only meaningful for the plain-text format.  For
        the other formats, you may specify the option when you
        call <command>pg_restore</command>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-b</></term>
      <term><option>--blobs</></term>
      <listitem>
       <para>
 	Include large objects in dump.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-c</option></term>
      <term><option>--clean</option></term>
      <listitem>
       <para>
        Output commands to clean (drop)
	database objects prior to (the commands for) creating them.
       </para>

       <para>
        This option is only meaningful for the plain-text format.  For
        the other formats, you may specify the option when you
        call <command>pg_restore</command>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-C</></term>
      <term><option>--create</></term>
      <listitem>
       <para>
	Begin the output with a command to create the
	database itself and reconnect to the created database.  (With a
	script of this form, it doesn't matter which database you connect
	to before running the script.)
       </para>

       <para>
        This option is only meaningful for the plain-text format.  For
        the other formats, you may specify the option when you
        call <command>pg_restore</command>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-d</option></term>
      <term><option>--inserts</option></term>
      <listitem>
       <para>
	Dump data as <command>INSERT</command> commands (rather
	than <command>COPY</command>). This will make restoration very
	slow, but it makes the archives more portable to other SQL database
	management systems.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-D</option></term>
      <term><option>--column-inserts</option></term>
      <term><option>--attribute-inserts</option></term>
      <listitem>
       <para>
	Dump data as <command>INSERT</command> commands with explicit
	column names (<literal>INSERT INTO
	<replaceable>table</replaceable>
	(<replaceable>column</replaceable>, ...) VALUES
	...</literal>).  This will make restoration very slow,
	but it is necessary if you desire to rearrange the column ordering.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-f <replaceable class="parameter">file</replaceable></option></term>
      <term><option>--file=<replaceable class="parameter">file</replaceable></option></term>
      <listitem>
       <para>
	Send output to the specified file.  If this is omitted, the
	standard output is used.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-F <replaceable class="parameter">format</replaceable></option></term>
      <term><option>--format=<replaceable class="parameter">format</replaceable></option></term>
      <listitem>
       <para>
        Selects the format of the output.
	<replaceable>format</replaceable> can be one of the following:

       <variablelist>
        <varlistentry>
         <term><literal>p</></term>
         <listitem>
          <para>
           Output a plain-text <acronym>SQL</acronym> script file (default)
          </para>
         </listitem>
        </varlistentry>

        <varlistentry>
         <term><literal>t</></term>
         <listitem>
          <para>
         Output a <command>tar</command> archive suitable for input into 
         <application>pg_restore</application>. Using this archive format 
         allows reordering and/or exclusion of schema elements 
         at the time the database is restored. It is also possible to limit 
         which data is reloaded at restore time.
          </para>
         </listitem>
        </varlistentry>

        <varlistentry>
         <term><literal>c</></term>
         <listitem>
          <para>
         Output a custom archive suitable for input into 
         <application>pg_restore</application>. This is the most flexible 
         format in that it allows reordering of data load as well 
         as schema elements. This format is also compressed by default.
          </para>
         </listitem>
        </varlistentry>

       </variablelist>
       </para>

      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-i</></term>
      <term><option>--ignore-version</></term>
      <listitem>
       <para>
        Ignore version mismatch between
        <application>pg_dump</application> and the database server.
       </para>

       <para>
        <application>pg_dump</application> can handle databases from
        previous releases of <productname>PostgreSQL</>, but very old
        versions are not supported anymore (currently prior to 7.0).
        Use this option if you need to override the version check (and
        if <application>pg_dump</application> then fails, don't say
        you weren't warned).
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-n <replaceable class="parameter">namespace</replaceable></option></term>
      <term><option>--schema=<replaceable class="parameter">schema</replaceable></option></term>
      <listitem>
       <para>
        Dump the contents of <replaceable class="parameter">schema</>
        only. If this option is not specified, all non-system schemas
        in the target database will be dumped.
       </para>

       <note>
        <para>
         In this mode, <application>pg_dump</application> makes no
         attempt to dump any other database objects that objects in the
	 selected schema may depend upon. Therefore, there is no
         guarantee that the results of a single-schema dump can be
         successfully restored by themselves into a clean database.
        </para>
       </note>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-o</></term>
      <term><option>--oids</></term>
      <listitem>
       <para>
	Dump object identifiers (<acronym>OID</acronym>s) for every
	table.  Use this option if your application references the <acronym>OID</>
	columns in some way (e.g., in a foreign key constraint).
	Otherwise, this option should not be used.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-O</></term>
      <term><option>--no-owner</option></term>
      <listitem>
       <para>
        Do not output commands to set
	ownership of objects to match the original database.
	By default, <application>pg_dump</application> issues
	<command>SET SESSION AUTHORIZATION</command>
	statements to set ownership of created schema elements.
	These statements
	will fail when the script is run unless it is started by a superuser
	(or the same user that owns all of the objects in the script).
	To make a script that can be restored by any user, but will give
	that user ownership of all the objects, specify <option>-O</>.
       </para>

       <para>
        This option is only meaningful for the plain-text format.  For
        the other formats, you may specify the option when you
        call <command>pg_restore</command>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-R</option></term>
      <term><option>--no-reconnect</option></term>
      <listitem>
       <para>
        This option is obsolete but still accepted for backwards
	compatibility.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-s</option></term>
      <term><option>--schema-only</option></term>
      <listitem>
       <para>
	Dump only the schema (data definitions), no data.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-S <replaceable class="parameter">username</replaceable></option></term>
      <term><option>--superuser=<replaceable class="parameter">username</replaceable></option></term>
      <listitem>
       <para>
        Specify the superuser user name to use when disabling triggers.
	This is only relevant if <option>--disable-triggers</> is used.
	(Usually, it's better to leave this out, and instead start the
	resulting script as superuser.)
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-t <replaceable class="parameter">table</replaceable></option></term>
      <term><option>--table=<replaceable class="parameter">table</replaceable></option></term>
      <listitem>
       <para>
	Dump data for <replaceable class="parameter">table</replaceable>
	only. It is possible for there to be
	multiple tables with the same name in different schemas; if that
	is the case, all matching tables will be dumped.  Specify both
	<option>--schema</> and <option>--table</> to select just one table.
       </para>

       <note>
        <para>
         In this mode, <application>pg_dump</application> makes no
         attempt to dump any other database objects that the selected table
	 may depend upon. Therefore, there is no guarantee
         that the results of a single-table dump can be successfully
         restored by themselves into a clean database.
        </para>
       </note>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-v</></term>
      <term><option>--verbose</></term>
      <listitem>
       <para>
	Specifies verbose mode.  This will cause
	<application>pg_dump</application> to print progress messages
	to standard error.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-x</></term>
      <term><option>--no-privileges</></term>
      <term><option>--no-acl</></term>
      <listitem>
       <para>
	Prevent dumping of access privileges (grant/revoke commands).
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-X use-set-session-authorization</></term>
      <term><option>--use-set-session-authorization</></term>
      <listitem>
       <para>
        This option is obsolete but still accepted for backwards
	compatibility.
        <application>pg_dump</application> now always behaves in the
	way formerly selected by this option.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-X disable-triggers</></term>
      <term><option>--disable-triggers</></term>
      <listitem>
       <para>
        This option is only relevant when creating a data-only dump.
	It instructs <application>pg_dump</application> to include commands
	to temporarily disable triggers on the target tables while
	the data is reloaded.  Use this if you have referential
	integrity checks or other triggers on the tables that you
	do not want to invoke during data reload.
       </para>

       <para>
        Presently, the commands emitted for <option>--disable-triggers</>
	must be done as superuser.  So, you should also specify
	a superuser name with <option>-S</>, or preferably be careful to
	start the resulting script as a superuser.
       </para>

       <para>
        This option is only meaningful for the plain-text format.  For
        the other formats, you may specify the option when you
        call <command>pg_restore</command>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-Z <replaceable class="parameter">0..9</replaceable></option></term>
      <term><option>--compress=<replaceable class="parameter">0..9</replaceable></option></term>
      <listitem>
       <para>
	Specify the compression level to use in archive formats that
	support compression.  (Currently only the custom archive
	format supports compression.)
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>

   <para>
    The following command-line options control the database connection parameters.

    <variablelist>
     <varlistentry>
      <term><option>-h <replaceable class="parameter">host</replaceable></option></term>
      <term><option>--host=<replaceable class="parameter">host</replaceable></option></term>
      <listitem>
       <para>
        Specifies the host name of the machine on which the server is
        running.  If the value begins with a slash, it is used as the
        directory for the Unix domain socket. The default is taken
        from the <envar>PGHOST</envar> environment variable, if set,
        else a Unix domain socket connection is attempted.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-p <replaceable class="parameter">port</replaceable></option></term>
      <term><option>--port=<replaceable class="parameter">port</replaceable></option></term>
      <listitem>
       <para>
	Specifies the TCP port or local Unix domain socket file
	extension on which the server is listening for connections.
	Defaults to the <envar>PGPORT</envar> environment variable, if
	set, or a compiled-in default.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-U <replaceable>username</replaceable></option></term>
      <listitem>
       <para>
        Connect as the given user
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><option>-W</option></term>
      <listitem>
       <para>
        Force a password prompt.  This should happen automatically if
        the server requires password authentication.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
 </refsect1>

 <refsect1>
  <title>Environment</title>

  <variablelist>
   <varlistentry>
    <term><envar>PGDATABASE</envar></term>
    <term><envar>PGHOST</envar></term>
    <term><envar>PGPORT</envar></term>
    <term><envar>PGUSER</envar></term>

    <listitem>
     <para>
      Default connection parameters.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1 id="app-pgdump-diagnostics">
  <title>Diagnostics</title>

  <para>
   <application>pg_dump</application> internally executes
   <command>SELECT</command> statements. If you have problems running
   <application>pg_dump</application>, make sure you are able to
   select information from the database using, for example, <xref
   linkend="app-psql">.
  </para>
 </refsect1>


 <refsect1 id="pg-dump-notes">
  <title>Notes</title>

  <para>
   If your database cluster has any local additions to the <literal>template1</> database,
   be careful to restore the output of <application>pg_dump</application> into a
   truly empty database; otherwise you are likely to get errors due to
   duplicate definitions of the added objects.  To make an empty database
   without any local additions, copy from <literal>template0</> not <literal>template1</>,
   for example:
<programlisting>
CREATE DATABASE foo WITH TEMPLATE template0;
</programlisting>
  </para>

  <para>
   <application>pg_dump</application> has a few limitations:

   <itemizedlist>
    <listitem>
     <para>
      When dumping a single table or as plain text, <application>pg_dump</application> 
      does not handle large objects. Large objects must be dumped with the
      entire database using one of the non-text archive formats.
     </para>
    </listitem>

    <listitem>
     <para>
      When a data-only dump is chosen and the option
      <option>--disable-triggers</> is used,
      <application>pg_dump</application> emits commands to disable
      triggers on user tables before inserting the data and commands
      to re-enable them after the data has been inserted.  If the
      restore is stopped in the middle, the system catalogs may be
      left in the wrong state.
     </para>
    </listitem>

   </itemizedlist>
  </para>

  <para>
   Members of tar archives are limited to a size less than 8 GB.
   (This is an inherent limitation of the tar file format.)  Therefore
   this format cannot be used if the textual representation of a table
   exceeds that size.  The total size of a tar archive and any of the
   other output formats is not limited, except possibly by the
   operating system.
  </para>

  <para>
   The dump file produced by <application>pg_dump</application> does
   not contain the statistics used by the optimizer to make query
   planning decisions.  Therefore, it is wise to run
   <command>ANALYZE</command> after restoring from a dump file to
   ensure good performance.
  </para>

 </refsect1>

 <refsect1 id="pg-dump-examples">
  <title>Examples</title>

  <para>
   To dump a database:
<screen>
<prompt>$</prompt> <userinput>pg_dump mydb &gt; db.out</userinput>
</screen>
  </para>

  <para>
   To reload this database:
<screen>
<prompt>$</prompt> <userinput>psql -d database -f db.out</userinput>
</screen>
  </para>

  <para>
   To dump a database called <literal>mydb</> that contains
   large objects to a <filename>tar</filename> file:

<screen>
<prompt>$</prompt> <userinput>pg_dump -Ft -b mydb &gt; db.tar</userinput>
</screen>
  </para>

  <para>
   To reload this database (with large objects) to an
   existing database called <literal>newdb</>:

<screen>
<prompt>$</prompt> <userinput>pg_restore -d newdb db.tar</userinput>
</screen>
  </para>

 </refsect1>

 <refsect1>
  <title>History</title>

  <para>
   The <application>pg_dump</application> utility first appeared in
   <application>Postgres95</application> release 0.02.  The
   non-plain-text output formats were introduced in
   <productname>PostgreSQL</productname> release 7.1.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="app-pg-dumpall"></member>
   <member><xref linkend="app-pgrestore"></member>
   <member><xref linkend="app-psql"></member>
  </simplelist>
 </refsect1>

</refentry>

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