Fix xslt_process() to ensure that it inserts a NULL terminator after the
[PostgreSQL.git] / doc / src / sgml / backup.sgml
blob372321ed1939a557337ec097099ec5c7a5b87d24
1 <!-- $PostgreSQL$ -->
3 <chapter id="backup">
4 <title>Backup and Restore</title>
6 <indexterm zone="backup"><primary>backup</></>
8 <para>
9 As with everything that contains valuable data, <productname>PostgreSQL</>
10 databases should be backed up regularly. While the procedure is
11 essentially simple, it is important to have a clear understanding of
12 the underlying techniques and assumptions.
13 </para>
15 <para>
16 There are three fundamentally different approaches to backing up
17 <productname>PostgreSQL</> data:
18 <itemizedlist>
19 <listitem><para><acronym>SQL</> dump</para></listitem>
20 <listitem><para>File system level backup</para></listitem>
21 <listitem><para>Continuous archiving</para></listitem>
22 </itemizedlist>
23 Each has its own strengths and weaknesses.
24 Each is discussed in turn below.
25 </para>
27 <sect1 id="backup-dump">
28 <title><acronym>SQL</> Dump</title>
30 <para>
31 The idea behind this dump method is to generate a text file with SQL
32 commands that, when fed back to the server, will recreate the
33 database in the same state as it was at the time of the dump.
34 <productname>PostgreSQL</> provides the utility program
35 <xref linkend="app-pgdump"> for this purpose. The basic usage of this
36 command is:
37 <synopsis>
38 pg_dump <replaceable class="parameter">dbname</replaceable> &gt; <replaceable class="parameter">outfile</replaceable>
39 </synopsis>
40 As you see, <application>pg_dump</> writes its results to the
41 standard output. We will see below how this can be useful.
42 </para>
44 <para>
45 <application>pg_dump</> is a regular <productname>PostgreSQL</>
46 client application (albeit a particularly clever one). This means
47 that you can do this backup procedure from any remote host that has
48 access to the database. But remember that <application>pg_dump</>
49 does not operate with special permissions. In particular, it must
50 have read access to all tables that you want to back up, so in
51 practice you almost always have to run it as a database superuser.
52 </para>
54 <para>
55 To specify which database server <application>pg_dump</> should
56 contact, use the command line options <option>-h
57 <replaceable>host</></> and <option>-p <replaceable>port</></>. The
58 default host is the local host or whatever your
59 <envar>PGHOST</envar> environment variable specifies. Similarly,
60 the default port is indicated by the <envar>PGPORT</envar>
61 environment variable or, failing that, by the compiled-in default.
62 (Conveniently, the server will normally have the same compiled-in
63 default.)
64 </para>
66 <para>
67 Like any other <productname>PostgreSQL</> client application,
68 <application>pg_dump</> will by default connect with the database
69 user name that is equal to the current operating system user name. To override
70 this, either specify the <option>-U</option> option or set the
71 environment variable <envar>PGUSER</envar>. Remember that
72 <application>pg_dump</> connections are subject to the normal
73 client authentication mechanisms (which are described in <xref
74 linkend="client-authentication">).
75 </para>
77 <para>
78 Dumps created by <application>pg_dump</> are internally consistent,
79 that is, the dump represents a snapshot of the database as of the time
80 <application>pg_dump</> begins running. <application>pg_dump</> does not
81 block other operations on the database while it is working.
82 (Exceptions are those operations that need to operate with an
83 exclusive lock, such as most forms of <command>ALTER TABLE</command>.)
84 </para>
86 <important>
87 <para>
88 If your database schema relies on OIDs (for instance as foreign
89 keys) you must instruct <application>pg_dump</> to dump the OIDs
90 as well. To do this, use the <option>-o</option> command line
91 option.
92 </para>
93 </important>
95 <sect2 id="backup-dump-restore">
96 <title>Restoring the dump</title>
98 <para>
99 The text files created by <application>pg_dump</> are intended to
100 be read in by the <application>psql</application> program. The
101 general command form to restore a dump is
102 <synopsis>
103 psql <replaceable class="parameter">dbname</replaceable> &lt; <replaceable class="parameter">infile</replaceable>
104 </synopsis>
105 where <replaceable class="parameter">infile</replaceable> is what
106 you used as <replaceable class="parameter">outfile</replaceable>
107 for the <application>pg_dump</> command. The database <replaceable
108 class="parameter">dbname</replaceable> will not be created by this
109 command, so you must create it yourself from <literal>template0</>
110 before executing <application>psql</> (e.g., with
111 <literal>createdb -T template0 <replaceable
112 class="parameter">dbname</></literal>). <application>psql</>
113 supports options similar to <application>pg_dump</>'s for specifying
114 the database server to connect to and the user name to use. See
115 the <xref linkend="app-psql"> reference page for more information.
116 </para>
118 <para>
119 Before restoring a SQL dump, all the users who own objects or were
120 granted permissions on objects in the dumped database must already
121 exist. If they do not, then the restore will fail to recreate the
122 objects with the original ownership and/or permissions.
123 (Sometimes this is what you want, but usually it is not.)
124 </para>
126 <para>
127 By default, the <application>psql</> script will continue to
128 execute after an SQL error is encountered. You might wish to use the
129 following command at the top of the script to alter that
130 behaviour and have <application>psql</application> exit with an
131 exit status of 3 if an SQL error occurs:
132 <programlisting>
133 \set ON_ERROR_STOP
134 </programlisting>
135 Either way, you will have an only partially restored database.
136 Alternatively, you can specify that the whole dump should be
137 restored as a single transaction, so the restore is either fully
138 completed or fully rolled back. This mode can be specified by
139 passing the <option>-1</> or <option>--single-transaction</>
140 command-line options to <application>psql</>. When using this
141 mode, be aware that even the smallest of errors can rollback a
142 restore that has already run for many hours. However, that might
143 still be preferable to manually cleaning up a complex database
144 after a partially restored dump.
145 </para>
147 <para>
148 The ability of <application>pg_dump</> and <application>psql</> to
149 write to or read from pipes makes it possible to dump a database
150 directly from one server to another, for example:
151 <programlisting>
152 pg_dump -h <replaceable>host1</> <replaceable>dbname</> | psql -h <replaceable>host2</> <replaceable>dbname</>
153 </programlisting>
154 </para>
156 <important>
157 <para>
158 The dumps produced by <application>pg_dump</> are relative to
159 <literal>template0</>. This means that any languages, procedures,
160 etc. added via <literal>template1</> will also be dumped by
161 <application>pg_dump</>. As a result, when restoring, if you are
162 using a customized <literal>template1</>, you must create the
163 empty database from <literal>template0</>, as in the example
164 above.
165 </para>
166 </important>
168 <para>
169 After restoring a backup, it is wise to run <xref
170 linkend="sql-analyze" endterm="sql-analyze-title"> on each
171 database so the query optimizer has useful statistics. An easy way
172 to do this is to run <command>vacuumdb -a -z</>; this is
173 equivalent to running <command>VACUUM ANALYZE</> on each database
174 manually. For more advice on how to load large amounts of data
175 into <productname>PostgreSQL</> efficiently, refer to <xref
176 linkend="populate">.
177 </para>
178 </sect2>
180 <sect2 id="backup-dump-all">
181 <title>Using <application>pg_dumpall</></title>
183 <para>
184 <application>pg_dump</> dumps only a single database at a time,
185 and it does not dump information about roles or tablespaces
186 (because those are cluster-wide rather than per-database).
187 To support convenient dumping of the entire contents of a database
188 cluster, the <xref linkend="app-pg-dumpall"> program is provided.
189 <application>pg_dumpall</> backs up each database in a given
190 cluster, and also preserves cluster-wide data such as role and
191 tablespace definitions. The basic usage of this command is:
192 <synopsis>
193 pg_dumpall &gt; <replaceable>outfile</>
194 </synopsis>
195 The resulting dump can be restored with <application>psql</>:
196 <synopsis>
197 psql -f <replaceable class="parameter">infile</replaceable> postgres
198 </synopsis>
199 (Actually, you can specify any existing database name to start from,
200 but if you are reloading into an empty cluster then <literal>postgres</>
201 should usually be used.) It is always necessary to have
202 database superuser access when restoring a <application>pg_dumpall</>
203 dump, as that is required to restore the role and tablespace information.
204 If you use tablespaces, be careful that the tablespace paths in the
205 dump are appropriate for the new installation.
206 </para>
208 <para>
209 <application>pg_dumpall</> works by emitting commands to re-create
210 roles, tablespaces, and empty databases, then invoking
211 <application>pg_dump</> for each database. This means that while
212 each database will be internally consistent, the snapshots of
213 different databases might not be exactly in-sync.
214 </para>
215 </sect2>
217 <sect2 id="backup-dump-large">
218 <title>Handling large databases</title>
220 <para>
221 Since <productname>PostgreSQL</productname> allows tables larger
222 than the maximum file size on your system, it can be problematic
223 to dump such a table to a file, since the resulting file will likely
224 be larger than the maximum size allowed by your system. Since
225 <application>pg_dump</> can write to the standard output, you can
226 use standard Unix tools to work around this possible problem.
227 There are several ways to do it:
228 </para>
230 <formalpara>
231 <title>Use compressed dumps.</title>
232 <para>
233 You can use your favorite compression program, for example
234 <application>gzip</application>:
236 <programlisting>
237 pg_dump <replaceable class="parameter">dbname</replaceable> | gzip &gt; <replaceable class="parameter">filename</replaceable>.gz
238 </programlisting>
240 Reload with:
242 <programlisting>
243 gunzip -c <replaceable class="parameter">filename</replaceable>.gz | psql <replaceable class="parameter">dbname</replaceable>
244 </programlisting>
248 <programlisting>
249 cat <replaceable class="parameter">filename</replaceable>.gz | gunzip | psql <replaceable class="parameter">dbname</replaceable>
250 </programlisting>
251 </para>
252 </formalpara>
254 <formalpara>
255 <title>Use <command>split</>.</title>
256 <para>
257 The <command>split</command> command
258 allows you to split the output into pieces that are
259 acceptable in size to the underlying file system. For example, to
260 make chunks of 1 megabyte:
262 <programlisting>
263 pg_dump <replaceable class="parameter">dbname</replaceable> | split -b 1m - <replaceable class="parameter">filename</replaceable>
264 </programlisting>
266 Reload with:
268 <programlisting>
269 cat <replaceable class="parameter">filename</replaceable>* | psql <replaceable class="parameter">dbname</replaceable>
270 </programlisting>
271 </para>
272 </formalpara>
274 <formalpara>
275 <title>Use <application>pg_dump</>'s custom dump format.</title>
276 <para>
277 If <productname>PostgreSQL</productname> was built on a system with the
278 <application>zlib</> compression library installed, the custom dump
279 format will compress data as it writes it to the output file. This will
280 produce dump file sizes similar to using <command>gzip</command>, but it
281 has the added advantage that tables can be restored selectively. The
282 following command dumps a database using the custom dump format:
284 <programlisting>
285 pg_dump -Fc <replaceable class="parameter">dbname</replaceable> &gt; <replaceable class="parameter">filename</replaceable>
286 </programlisting>
288 A custom-format dump is not a script for <application>psql</>, but
289 instead must be restored with <application>pg_restore</>, for example:
291 <programlisting>
292 pg_restore -d <replaceable class="parameter">dbname</replaceable> <replaceable class="parameter">filename</replaceable>
293 </programlisting>
295 See the <xref linkend="app-pgdump"> and <xref
296 linkend="app-pgrestore"> reference pages for details.
297 </para>
298 </formalpara>
300 <para>
301 For very large databases, you might need to combine <command>split</>
302 with one of the other two approaches.
303 </para>
305 </sect2>
306 </sect1>
308 <sect1 id="backup-file">
309 <title>File System Level Backup</title>
311 <para>
312 An alternative backup strategy is to directly copy the files that
313 <productname>PostgreSQL</> uses to store the data in the database. In
314 <xref linkend="creating-cluster"> it is explained where these files
315 are located, but you have probably found them already if you are
316 interested in this method. You can use whatever method you prefer
317 for doing usual file system backups, for example:
319 <programlisting>
320 tar -cf backup.tar /usr/local/pgsql/data
321 </programlisting>
322 </para>
324 <para>
325 There are two restrictions, however, which make this method
326 impractical, or at least inferior to the <application>pg_dump</>
327 method:
329 <orderedlist>
330 <listitem>
331 <para>
332 The database server <emphasis>must</> be shut down in order to
333 get a usable backup. Half-way measures such as disallowing all
334 connections will <emphasis>not</emphasis> work
335 (in part because <command>tar</command> and similar tools do not take
336 an atomic snapshot of the state of the file system,
337 but also because of internal buffering within the server).
338 Information about stopping the server can be found in
339 <xref linkend="server-shutdown">. Needless to say that you
340 also need to shut down the server before restoring the data.
341 </para>
342 </listitem>
344 <listitem>
345 <para>
346 If you have dug into the details of the file system layout of the
347 database, you might be tempted to try to back up or restore only certain
348 individual tables or databases from their respective files or
349 directories. This will <emphasis>not</> work because the
350 information contained in these files contains only half the
351 truth. The other half is in the commit log files
352 <filename>pg_clog/*</filename>, which contain the commit status of
353 all transactions. A table file is only usable with this
354 information. Of course it is also impossible to restore only a
355 table and the associated <filename>pg_clog</filename> data
356 because that would render all other tables in the database
357 cluster useless. So file system backups only work for complete
358 backup and restoration of an entire database cluster.
359 </para>
360 </listitem>
361 </orderedlist>
362 </para>
364 <para>
365 An alternative file-system backup approach is to make a
366 <quote>consistent snapshot</quote> of the data directory, if the
367 file system supports that functionality (and you are willing to
368 trust that it is implemented correctly). The typical procedure is
369 to make a <quote>frozen snapshot</> of the volume containing the
370 database, then copy the whole data directory (not just parts, see
371 above) from the snapshot to a backup device, then release the frozen
372 snapshot. This will work even while the database server is running.
373 However, a backup created in this way saves
374 the database files in a state where the database server was not
375 properly shut down; therefore, when you start the database server
376 on the backed-up data, it will think the previous server instance had
377 crashed and replay the WAL log. This is not a problem, just be aware of
378 it (and be sure to include the WAL files in your backup).
379 </para>
381 <para>
382 If your database is spread across multiple file systems, there might not
383 be any way to obtain exactly-simultaneous frozen snapshots of all
384 the volumes. For example, if your data files and WAL log are on different
385 disks, or if tablespaces are on different file systems, it might
386 not be possible to use snapshot backup because the snapshots
387 <emphasis>must</> be simultaneous.
388 Read your file system documentation very carefully before trusting
389 to the consistent-snapshot technique in such situations.
390 </para>
392 <para>
393 If simultaneous snapshots are not possible, one option is to shut down
394 the database server long enough to establish all the frozen snapshots.
395 Another option is perform a continuous archiving base backup (<xref
396 linkend="backup-base-backup">) because such backups are immune to file
397 system changes during the backup. This requires enabling continuous
398 archiving just during the backup process; restore is done using
399 continuous archive recovery (<xref linkend="backup-pitr-recovery">).
400 </para>
402 <para>
403 Another option is to use <application>rsync</> to perform a file
404 system backup. This is done by first running <application>rsync</>
405 while the database server is running, then shutting down the database
406 server just long enough to do a second <application>rsync</>. The
407 second <application>rsync</> will be much quicker than the first,
408 because it has relatively little data to transfer, and the end result
409 will be consistent because the server was down. This method
410 allows a file system backup to be performed with minimal downtime.
411 </para>
413 <para>
414 Note that a file system backup will not necessarily be
415 smaller than an SQL dump. On the contrary, it will most likely be
416 larger. (<application>pg_dump</application> does not need to dump
417 the contents of indexes for example, just the commands to recreate
418 them.) However, taking a file system backup might be faster.
419 </para>
420 </sect1>
422 <sect1 id="continuous-archiving">
423 <title>Continuous Archiving and Point-In-Time Recovery (PITR)</title>
425 <indexterm zone="backup">
426 <primary>continuous archiving</primary>
427 </indexterm>
429 <indexterm zone="backup">
430 <primary>point-in-time recovery</primary>
431 </indexterm>
433 <indexterm zone="backup">
434 <primary>PITR</primary>
435 </indexterm>
437 <para>
438 At all times, <productname>PostgreSQL</> maintains a
439 <firstterm>write ahead log</> (WAL) in the <filename>pg_xlog/</>
440 subdirectory of the cluster's data directory. The log describes
441 every change made to the database's data files. This log exists
442 primarily for crash-safety purposes: if the system crashes, the
443 database can be restored to consistency by <quote>replaying</> the
444 log entries made since the last checkpoint. However, the existence
445 of the log makes it possible to use a third strategy for backing up
446 databases: we can combine a file-system-level backup with backup of
447 the WAL files. If recovery is needed, we restore the backup and
448 then replay from the backed-up WAL files to bring the backup up to
449 current time. This approach is more complex to administer than
450 either of the previous approaches, but it has some significant
451 benefits:
452 <itemizedlist>
453 <listitem>
454 <para>
455 We do not need a perfectly consistent backup as the starting point.
456 Any internal inconsistency in the backup will be corrected by log
457 replay (this is not significantly different from what happens during
458 crash recovery). So we don't need file system snapshot capability,
459 just <application>tar</> or a similar archiving tool.
460 </para>
461 </listitem>
462 <listitem>
463 <para>
464 Since we can string together an indefinitely long sequence of WAL files
465 for replay, continuous backup can be achieved simply by continuing to archive
466 the WAL files. This is particularly valuable for large databases, where
467 it might not be convenient to take a full backup frequently.
468 </para>
469 </listitem>
470 <listitem>
471 <para>
472 There is nothing that says we have to replay the WAL entries all the
473 way to the end. We could stop the replay at any point and have a
474 consistent snapshot of the database as it was at that time. Thus,
475 this technique supports <firstterm>point-in-time recovery</>: it is
476 possible to restore the database to its state at any time since your base
477 backup was taken.
478 </para>
479 </listitem>
480 <listitem>
481 <para>
482 If we continuously feed the series of WAL files to another
483 machine that has been loaded with the same base backup file, we
484 have a <firstterm>warm standby</> system: at any point we can bring up
485 the second machine and it will have a nearly-current copy of the
486 database.
487 </para>
488 </listitem>
489 </itemizedlist>
490 </para>
492 <para>
493 As with the plain file-system-backup technique, this method can only
494 support restoration of an entire database cluster, not a subset.
495 Also, it requires a lot of archival storage: the base backup might be bulky,
496 and a busy system will generate many megabytes of WAL traffic that
497 have to be archived. Still, it is the preferred backup technique in
498 many situations where high reliability is needed.
499 </para>
501 <para>
502 To recover successfully using continuous archiving (also called
503 <quote>online backup</> by many database vendors), you need a continuous
504 sequence of archived WAL files that extends back at least as far as the
505 start time of your backup. So to get started, you should set up and test
506 your procedure for archiving WAL files <emphasis>before</> you take your
507 first base backup. Accordingly, we first discuss the mechanics of
508 archiving WAL files.
509 </para>
511 <sect2 id="backup-archiving-wal">
512 <title>Setting up WAL archiving</title>
514 <para>
515 In an abstract sense, a running <productname>PostgreSQL</> system
516 produces an indefinitely long sequence of WAL records. The system
517 physically divides this sequence into WAL <firstterm>segment
518 files</>, which are normally 16MB apiece (although the segment size
519 can be altered when building <productname>PostgreSQL</>). The segment
520 files are given numeric names that reflect their position in the
521 abstract WAL sequence. When not using WAL archiving, the system
522 normally creates just a few segment files and then
523 <quote>recycles</> them by renaming no-longer-needed segment files
524 to higher segment numbers. It's assumed that a segment file whose
525 contents precede the checkpoint-before-last is no longer of
526 interest and can be recycled.
527 </para>
529 <para>
530 When archiving WAL data, we need to capture the contents of each segment
531 file once it is filled, and save that data somewhere before the segment
532 file is recycled for reuse. Depending on the application and the
533 available hardware, there could be many different ways of <quote>saving
534 the data somewhere</>: we could copy the segment files to an NFS-mounted
535 directory on another machine, write them onto a tape drive (ensuring that
536 you have a way of identifying the original name of each file), or batch
537 them together and burn them onto CDs, or something else entirely. To
538 provide the database administrator with as much flexibility as possible,
539 <productname>PostgreSQL</> tries not to make any assumptions about how
540 the archiving will be done. Instead, <productname>PostgreSQL</> lets
541 the administrator specify a shell command to be executed to copy a
542 completed segment file to wherever it needs to go. The command could be
543 as simple as a <literal>cp</>, or it could invoke a complex shell
544 script &mdash; it's all up to you.
545 </para>
547 <para>
548 To enable WAL archiving, set the <xref
549 linkend="guc-archive-mode"> configuration parameter to <literal>on</>,
550 and specify the shell command to use in the <xref
551 linkend="guc-archive-command"> configuration parameter. In practice
552 these settings will always be placed in the
553 <filename>postgresql.conf</filename> file.
554 In <varname>archive_command</>,
555 any <literal>%p</> is replaced by the path name of the file to
556 archive, while any <literal>%f</> is replaced by the file name only.
557 (The path name is relative to the current working directory,
558 i.e., the cluster's data directory.)
559 Write <literal>%%</> if you need to embed an actual <literal>%</>
560 character in the command. The simplest useful command is something
561 like:
562 <programlisting>
563 archive_command = 'cp -i %p /mnt/server/archivedir/%f &lt;/dev/null'
564 </programlisting>
565 which will copy archivable WAL segments to the directory
566 <filename>/mnt/server/archivedir</>. (This is an example, not a
567 recommendation, and might not work on all platforms.) After the
568 <literal>%p</> and <literal>%f</> parameters have been replaced,
569 the actual command executed might look like this:
570 <programlisting>
571 cp -i pg_xlog/00000001000000A900000065 /mnt/server/archivedir/00000001000000A900000065 &lt;/dev/null
572 </programlisting>
573 A similar command will be generated for each new file to be archived.
574 </para>
576 <para>
577 The archive command will be executed under the ownership of the same
578 user that the <productname>PostgreSQL</> server is running as. Since
579 the series of WAL files being archived contains effectively everything
580 in your database, you will want to be sure that the archived data is
581 protected from prying eyes; for example, archive into a directory that
582 does not have group or world read access.
583 </para>
585 <para>
586 It is important that the archive command return zero exit status if and
587 only if it succeeded. Upon getting a zero result,
588 <productname>PostgreSQL</> will assume that the file has been
589 successfully archived, and will remove or recycle it. However, a nonzero
590 status tells <productname>PostgreSQL</> that the file was not archived;
591 it will try again periodically until it succeeds.
592 </para>
594 <para>
595 The archive command should generally be designed to refuse to overwrite
596 any pre-existing archive file. This is an important safety feature to
597 preserve the integrity of your archive in case of administrator error
598 (such as sending the output of two different servers to the same archive
599 directory).
600 It is advisable to test your proposed archive command to ensure that it
601 indeed does not overwrite an existing file, <emphasis>and that it returns
602 nonzero status in this case</>. We have found that <literal>cp -i</> does
603 this correctly on some platforms but not others. If the chosen command
604 does not itself handle this case correctly, you should add a command
605 to test for pre-existence of the archive file. For example, something
606 like:
607 <programlisting>
608 archive_command = 'test ! -f .../%f &amp;&amp; cp %p .../%f'
609 </programlisting>
610 works correctly on most Unix variants.
611 </para>
613 <para>
614 While designing your archiving setup, consider what will happen if
615 the archive command fails repeatedly because some aspect requires
616 operator intervention or the archive runs out of space. For example, this
617 could occur if you write to tape without an autochanger; when the tape
618 fills, nothing further can be archived until the tape is swapped.
619 You should ensure that any error condition or request to a human operator
620 is reported appropriately so that the situation can be
621 resolved reasonably quickly. The <filename>pg_xlog/</> directory will
622 continue to fill with WAL segment files until the situation is resolved.
623 (If the filesystem containing <filename>pg_xlog/</> fills up,
624 <productname>PostgreSQL</> will do a PANIC shutdown. No prior
625 transactions will be lost, but the database will be unavailable until
626 you free some space.)
627 </para>
629 <para>
630 The speed of the archiving command is not important, so long as it can keep up
631 with the average rate at which your server generates WAL data. Normal
632 operation continues even if the archiving process falls a little behind.
633 If archiving falls significantly behind, this will increase the amount of
634 data that would be lost in the event of a disaster. It will also mean that
635 the <filename>pg_xlog/</> directory will contain large numbers of
636 not-yet-archived segment files, which could eventually exceed available
637 disk space. You are advised to monitor the archiving process to ensure that
638 it is working as you intend.
639 </para>
641 <para>
642 In writing your archive command, you should assume that the file names to
643 be archived can be up to 64 characters long and can contain any
644 combination of ASCII letters, digits, and dots. It is not necessary to
645 remember the original relative path (<literal>%p</>) but it is necessary to
646 remember the file name (<literal>%f</>).
647 </para>
649 <para>
650 Note that although WAL archiving will allow you to restore any
651 modifications made to the data in your <productname>PostgreSQL</> database,
652 it will not restore changes made to configuration files (that is,
653 <filename>postgresql.conf</>, <filename>pg_hba.conf</> and
654 <filename>pg_ident.conf</>), since those are edited manually rather
655 than through SQL operations.
656 You might wish to keep the configuration files in a location that will
657 be backed up by your regular file system backup procedures. See
658 <xref linkend="runtime-config-file-locations"> for how to relocate the
659 configuration files.
660 </para>
662 <para>
663 The archive command is only invoked on completed WAL segments. Hence,
664 if your server generates only little WAL traffic (or has slack periods
665 where it does so), there could be a long delay between the completion
666 of a transaction and its safe recording in archive storage. To put
667 a limit on how old unarchived data can be, you can set
668 <xref linkend="guc-archive-timeout"> to force the server to switch
669 to a new WAL segment file at least that often. Note that archived
670 files that are ended early due to a forced switch are still the same
671 length as completely full files. It is therefore unwise to set a very
672 short <varname>archive_timeout</> &mdash; it will bloat your archive
673 storage. <varname>archive_timeout</> settings of a minute or so are
674 usually reasonable.
675 </para>
677 <para>
678 Also, you can force a segment switch manually with
679 <function>pg_switch_xlog</>, if you want to ensure that a
680 just-finished transaction is archived as soon as possible. Other utility
681 functions related to WAL management are listed in <xref
682 linkend="functions-admin-backup-table">.
683 </para>
685 <para>
686 When <varname>archive_mode</> is <literal>off</> some SQL commands
687 are optimized to avoid WAL logging, as described in <xref
688 linkend="populate-pitr">. If archiving were turned on during execution
689 of one of these statements, WAL would not contain enough information
690 for archive recovery. (Crash recovery is unaffected.) For
691 this reason, <varname>archive_mode</> can only be changed at server
692 start. However, <varname>archive_command</> can be changed with a
693 configuration file reload. If you wish to temporarily stop archiving,
694 one way to do it is to set <varname>archive_command</> to the empty
695 string (<literal>''</>).
696 This will cause WAL files to accumulate in <filename>pg_xlog/</> until a
697 working <varname>archive_command</> is re-established.
698 </para>
699 </sect2>
701 <sect2 id="backup-base-backup">
702 <title>Making a Base Backup</title>
704 <para>
705 The procedure for making a base backup is relatively simple:
706 <orderedlist>
707 <listitem>
708 <para>
709 Ensure that WAL archiving is enabled and working.
710 </para>
711 </listitem>
712 <listitem>
713 <para>
714 Connect to the database as a superuser, and issue the command:
715 <programlisting>
716 SELECT pg_start_backup('label');
717 </programlisting>
718 where <literal>label</> is any string you want to use to uniquely
719 identify this backup operation. (One good practice is to use the
720 full path where you intend to put the backup dump file.)
721 <function>pg_start_backup</> creates a <firstterm>backup label</> file,
722 called <filename>backup_label</>, in the cluster directory with
723 information about your backup.
724 </para>
726 <para>
727 It does not matter which database within the cluster you connect to to
728 issue this command. You can ignore the result returned by the function;
729 but if it reports an error, deal with that before proceeding.
730 </para>
732 <para>
733 By default, <function>pg_start_backup</> can take a long time to finish.
734 This is because it performs a checkpoint, and the I/O
735 required for the checkpoint will be spread out over a significant
736 period of time, by default half your inter-checkpoint interval
737 (see the configuration parameter
738 <xref linkend="guc-checkpoint-completion-target">). Usually
739 this is what you want, because it minimizes the impact on query
740 processing. If you just want to start the backup as soon as
741 possible, use:
742 <programlisting>
743 SELECT pg_start_backup('label', true);
744 </programlisting>
745 This forces the checkpoint to be done as quickly as possible.
746 </para>
747 </listitem>
748 <listitem>
749 <para>
750 Perform the backup, using any convenient file-system-backup tool
751 such as <application>tar</> or <application>cpio</>. It is neither
752 necessary nor desirable to stop normal operation of the database
753 while you do this.
754 </para>
755 </listitem>
756 <listitem>
757 <para>
758 Again connect to the database as a superuser, and issue the command:
759 <programlisting>
760 SELECT pg_stop_backup();
761 </programlisting>
762 This terminates the backup mode and performs an automatic switch to
763 the next WAL segment. The reason for the switch is to arrange that
764 the last WAL segment file written during the backup interval is
765 immediately ready to archive.
766 </para>
767 </listitem>
768 <listitem>
769 <para>
770 Once the WAL segment files used during the backup are archived, you are
771 done. The file identified by <function>pg_stop_backup</>'s result is
772 the last segment that is required to form a complete set of backup files.
773 <function>pg_stop_backup</> does not return until the last segment has
774 been archived.
775 Archiving of these files happens automatically since you have
776 already configured <varname>archive_command</>. In most cases this
777 happens quickly, but you are advised to monitor your archive
778 system to ensure there are no delays.
779 If the archive process has fallen behind
780 because of failures of the archive command, it will keep retrying
781 until the archive succeeds and the backup is complete.
782 If you wish to place a time limit on the execution of
783 <function>pg_stop_backup</>, set an appropriate
784 <varname>statement_timeout</varname> value.
785 </para>
786 </listitem>
787 </orderedlist>
788 </para>
790 <para>
791 Some backup tools that you might wish to use emit warnings or errors
792 if the files they are trying to copy change while the copy proceeds.
793 This situation is normal, and not an error, when taking a base backup
794 of an active database; so you need to ensure that you can distinguish
795 complaints of this sort from real errors. For example, some versions
796 of <application>rsync</> return a separate exit code for
797 <quote>vanished source files</>, and you can write a driver script to
798 accept this exit code as a non-error case. Also, some versions of
799 GNU <application>tar</> return an error code indistinguishable from
800 a fatal error if a file was truncated while <application>tar</> was
801 copying it. Fortunately, GNU <application>tar</> versions 1.16 and
802 later exit with <literal>1</> if a file was changed during the backup,
803 and <literal>2</> for other errors.
804 </para>
806 <para>
807 It is not necessary to be very concerned about the amount of time elapsed
808 between <function>pg_start_backup</> and the start of the actual backup,
809 nor between the end of the backup and <function>pg_stop_backup</>; a
810 few minutes' delay won't hurt anything. (However, if you normally run the
811 server with <varname>full_page_writes</> disabled, you might notice a drop
812 in performance between <function>pg_start_backup</> and
813 <function>pg_stop_backup</>, since <varname>full_page_writes</> is
814 effectively forced on during backup mode.) You must ensure that these
815 steps are carried out in sequence without any possible
816 overlap, or you will invalidate the backup.
817 </para>
819 <para>
820 Be certain that your backup dump includes all of the files underneath
821 the database cluster directory (e.g., <filename>/usr/local/pgsql/data</>).
822 If you are using tablespaces that do not reside underneath this directory,
823 be careful to include them as well (and be sure that your backup dump
824 archives symbolic links as links, otherwise the restore will mess up
825 your tablespaces).
826 </para>
828 <para>
829 You can, however, omit from the backup dump the files within the
830 <filename>pg_xlog/</> subdirectory of the cluster directory. This
831 slight complication is worthwhile because it reduces the risk
832 of mistakes when restoring. This is easy to arrange if
833 <filename>pg_xlog/</> is a symbolic link pointing to someplace outside
834 the cluster directory, which is a common setup anyway for performance
835 reasons.
836 </para>
838 <para>
839 To make use of the backup, you will need to keep around all the WAL
840 segment files generated during and after the file system backup.
841 To aid you in doing this, the <function>pg_stop_backup</> function
842 creates a <firstterm>backup history file</> that is immediately
843 stored into the WAL archive area. This file is named after the first
844 WAL segment file that you need to have to make use of the backup.
845 For example, if the starting WAL file is
846 <literal>0000000100001234000055CD</> the backup history file will be
847 named something like
848 <literal>0000000100001234000055CD.007C9330.backup</>. (The second
849 part of the file name stands for an exact position within the WAL
850 file, and can ordinarily be ignored.) Once you have safely archived
851 the file system backup and the WAL segment files used during the
852 backup (as specified in the backup history file), all archived WAL
853 segments with names numerically less are no longer needed to recover
854 the file system backup and can be deleted. However, you should
855 consider keeping several backup sets to be absolutely certain that
856 you can recover your data.
857 </para>
859 <para>
860 The backup history file is just a small text file. It contains the
861 label string you gave to <function>pg_start_backup</>, as well as
862 the starting and ending times and WAL segments of the backup.
863 If you used the label to identify where the associated dump file is kept,
864 then the archived history file is enough to tell you which dump file to
865 restore, should you need to do so.
866 </para>
868 <para>
869 Since you have to keep around all the archived WAL files back to your
870 last base backup, the interval between base backups should usually be
871 chosen based on how much storage you want to expend on archived WAL
872 files. You should also consider how long you are prepared to spend
873 recovering, if recovery should be necessary &mdash; the system will have to
874 replay all those WAL segments, and that could take awhile if it has
875 been a long time since the last base backup.
876 </para>
878 <para>
879 It's also worth noting that the <function>pg_start_backup</> function
880 makes a file named <filename>backup_label</> in the database cluster
881 directory, which is then removed again by <function>pg_stop_backup</>.
882 This file will of course be archived as a part of your backup dump file.
883 The backup label file includes the label string you gave to
884 <function>pg_start_backup</>, as well as the time at which
885 <function>pg_start_backup</> was run, and the name of the starting WAL
886 file. In case of confusion it will
887 therefore be possible to look inside a backup dump file and determine
888 exactly which backup session the dump file came from.
889 </para>
891 <para>
892 It is also possible to make a backup dump while the server is
893 stopped. In this case, you obviously cannot use
894 <function>pg_start_backup</> or <function>pg_stop_backup</>, and
895 you will therefore be left to your own devices to keep track of which
896 backup dump is which and how far back the associated WAL files go.
897 It is generally better to follow the continuous archiving procedure above.
898 </para>
899 </sect2>
901 <sect2 id="backup-pitr-recovery">
902 <title>Recovering using a Continuous Archive Backup</title>
904 <para>
905 Okay, the worst has happened and you need to recover from your backup.
906 Here is the procedure:
907 <orderedlist>
908 <listitem>
909 <para>
910 Stop the server, if it's running.
911 </para>
912 </listitem>
913 <listitem>
914 <para>
915 If you have the space to do so,
916 copy the whole cluster data directory and any tablespaces to a temporary
917 location in case you need them later. Note that this precaution will
918 require that you have enough free space on your system to hold two
919 copies of your existing database. If you do not have enough space,
920 you need at the least to copy the contents of the <filename>pg_xlog</>
921 subdirectory of the cluster data directory, as it might contain logs which
922 were not archived before the system went down.
923 </para>
924 </listitem>
925 <listitem>
926 <para>
927 Clean out all existing files and subdirectories under the cluster data
928 directory and under the root directories of any tablespaces you are using.
929 </para>
930 </listitem>
931 <listitem>
932 <para>
933 Restore the database files from your base backup. Be careful that they
934 are restored with the right ownership (the database system user, not
935 <literal>root</>!) and with the right permissions. If you are using
936 tablespaces,
937 you should verify that the symbolic links in <filename>pg_tblspc/</>
938 were correctly restored.
939 </para>
940 </listitem>
941 <listitem>
942 <para>
943 Remove any files present in <filename>pg_xlog/</>; these came from the
944 backup dump and are therefore probably obsolete rather than current.
945 If you didn't archive <filename>pg_xlog/</> at all, then recreate it,
946 being careful to ensure that you re-establish it as a symbolic link
947 if you had it set up that way before.
948 </para>
949 </listitem>
950 <listitem>
951 <para>
952 If you had unarchived WAL segment files that you saved in step 2,
953 copy them into <filename>pg_xlog/</>. (It is best to copy them,
954 not move them, so that you still have the unmodified files if a
955 problem occurs and you have to start over.)
956 </para>
957 </listitem>
958 <listitem>
959 <para>
960 Create a recovery command file <filename>recovery.conf</> in the cluster
961 data directory (see <xref linkend="recovery-config-settings">). You might
962 also want to temporarily modify <filename>pg_hba.conf</> to prevent
963 ordinary users from connecting until you are sure the recovery has worked.
964 </para>
965 </listitem>
966 <listitem>
967 <para>
968 Start the server. The server will go into recovery mode and
969 proceed to read through the archived WAL files it needs. Should the
970 recovery be terminated because of an external error, the server can
971 simply be restarted and it will continue recovery. Upon completion
972 of the recovery process, the server will rename
973 <filename>recovery.conf</> to <filename>recovery.done</> (to prevent
974 accidentally re-entering recovery mode in case of a crash later) and then
975 commence normal database operations.
976 </para>
977 </listitem>
978 <listitem>
979 <para>
980 Inspect the contents of the database to ensure you have recovered to
981 where you want to be. If not, return to step 1. If all is well,
982 let in your users by restoring <filename>pg_hba.conf</> to normal.
983 </para>
984 </listitem>
985 </orderedlist>
986 </para>
988 <para>
989 The key part of all this is to set up a recovery command file that
990 describes how you want to recover and how far the recovery should
991 run. You can use <filename>recovery.conf.sample</> (normally
992 installed in the installation <filename>share/</> directory) as a
993 prototype. The one thing that you absolutely must specify in
994 <filename>recovery.conf</> is the <varname>restore_command</>,
995 which tells <productname>PostgreSQL</> how to get back archived
996 WAL file segments. Like the <varname>archive_command</>, this is
997 a shell command string. It can contain <literal>%f</>, which is
998 replaced by the name of the desired log file, and <literal>%p</>,
999 which is replaced by the path name to copy the log file to.
1000 (The path name is relative to the current working directory,
1001 i.e., the cluster's data directory.)
1002 Write <literal>%%</> if you need to embed an actual <literal>%</>
1003 character in the command. The simplest useful command is
1004 something like:
1005 <programlisting>
1006 restore_command = 'cp /mnt/server/archivedir/%f %p'
1007 </programlisting>
1008 which will copy previously archived WAL segments from the directory
1009 <filename>/mnt/server/archivedir</>. You could of course use something
1010 much more complicated, perhaps even a shell script that requests the
1011 operator to mount an appropriate tape.
1012 </para>
1014 <para>
1015 It is important that the command return nonzero exit status on failure.
1016 The command <emphasis>will</> be asked for files that are not present
1017 in the archive; it must return nonzero when so asked. This is not an
1018 error condition. Not all of the requested files will be WAL segment
1019 files; you should also expect requests for files with a suffix of
1020 <literal>.backup</> or <literal>.history</>. Also be aware that
1021 the base name of the <literal>%p</> path will be different from
1022 <literal>%f</>; do not expect them to be interchangeable.
1023 </para>
1025 <para>
1026 WAL segments that cannot be found in the archive will be sought in
1027 <filename>pg_xlog/</>; this allows use of recent un-archived segments.
1028 However segments that are available from the archive will be used in
1029 preference to files in <filename>pg_xlog/</>. The system will not
1030 overwrite the existing contents of <filename>pg_xlog/</> when retrieving
1031 archived files.
1032 </para>
1034 <para>
1035 Normally, recovery will proceed through all available WAL segments,
1036 thereby restoring the database to the current point in time (or as
1037 close as we can get given the available WAL segments). So a normal
1038 recovery will end with a <quote>file not found</> message, the exact text
1039 of the error message depending upon your choice of
1040 <varname>restore_command</>. You may also see an error message
1041 at the start of recovery for a file named something like
1042 <filename>00000001.history</>. This is also normal and does not
1043 indicate a problem in simple recovery situations. See
1044 <xref linkend="backup-timelines"> for discussion.
1045 </para>
1047 <para>
1048 If you want to recover to some previous point in time (say, right before
1049 the junior DBA dropped your main transaction table), just specify the
1050 required stopping point in <filename>recovery.conf</>. You can specify
1051 the stop point, known as the <quote>recovery target</>, either by
1052 date/time or by completion of a specific transaction ID. As of this
1053 writing only the date/time option is very usable, since there are no tools
1054 to help you identify with any accuracy which transaction ID to use.
1055 </para>
1057 <note>
1058 <para>
1059 The stop point must be after the ending time of the base backup, i.e.,
1060 the end time of <function>pg_stop_backup</>. You cannot use a base backup
1061 to recover to a time when that backup was still going on. (To
1062 recover to such a time, you must go back to your previous base backup
1063 and roll forward from there.)
1064 </para>
1065 </note>
1067 <para>
1068 If recovery finds a corruption in the WAL data then recovery will
1069 complete at that point and the server will not start. In such a case the
1070 recovery process could be re-run from the beginning, specifying a
1071 <quote>recovery target</> before the point of corruption so that recovery
1072 can complete normally.
1073 If recovery fails for an external reason, such as a system crash or
1074 if the WAL archive has become inaccessible, then the recovery can simply
1075 be restarted and it will restart almost from where it failed.
1076 Recovery restart works much like checkpointing in normal operation:
1077 the server periodically forces all its state to disk, and then updates
1078 the <filename>pg_control</> file to indicate that the already-processed
1079 WAL data need not be scanned again.
1080 </para>
1083 <sect3 id="recovery-config-settings" xreflabel="Recovery Settings">
1084 <title>Recovery Settings</title>
1086 <para>
1087 These settings can only be made in the <filename>recovery.conf</>
1088 file, and apply only for the duration of the recovery. They must be
1089 reset for any subsequent recovery you wish to perform. They cannot be
1090 changed once recovery has begun.
1091 </para>
1093 <variablelist>
1095 <varlistentry id="restore-command" xreflabel="restore_command">
1096 <term><varname>restore_command</varname> (<type>string</type>)</term>
1097 <listitem>
1098 <para>
1099 The shell command to execute to retrieve an archived segment of
1100 the WAL file series. This parameter is required.
1101 Any <literal>%f</> in the string is
1102 replaced by the name of the file to retrieve from the archive,
1103 and any <literal>%p</> is replaced by the path name to copy
1104 it to on the server.
1105 (The path name is relative to the current working directory,
1106 i.e., the cluster's data directory.)
1107 Any <literal>%r</> is replaced by the name of the file containing the
1108 last valid restart point. That is the earliest file that must be kept
1109 to allow a restore to be restartable, so this information can be used
1110 to truncate the archive to just the minimum required to support
1111 restart from the current restore. <literal>%r</> would typically be
1112 used in a warm-standby configuration
1113 (see <xref linkend="warm-standby">).
1114 Write <literal>%%</> to embed an actual <literal>%</> character
1115 in the command.
1116 </para>
1117 <para>
1118 It is important for the command to return a zero exit status if and
1119 only if it succeeds. The command <emphasis>will</> be asked for file
1120 names that are not present in the archive; it must return nonzero
1121 when so asked. Examples:
1122 <programlisting>
1123 restore_command = 'cp /mnt/server/archivedir/%f "%p"'
1124 restore_command = 'copy "C:\\server\\archivedir\\%f" "%p"' # Windows
1125 </programlisting>
1126 </para>
1127 </listitem>
1128 </varlistentry>
1130 <varlistentry id="recovery-end-command" xreflabel="recovery_end_command">
1131 <term><varname>recovery_end_command</varname> (<type>string</type>)</term>
1132 <listitem>
1133 <para>
1134 This parameter specifies a shell command that will be executed once only
1135 at the end of recovery. This parameter is optional. The purpose of the
1136 <varname>recovery_end_command</> is to provide a mechanism for cleanup
1137 following replication or recovery.
1138 Any <literal>%r</> is replaced by the name of the file
1139 containing the last valid restart point. That is the earliest file that
1140 must be kept to allow a restore to be restartable, so this information
1141 can be used to truncate the archive to just the minimum required to
1142 support restart from the current restore. <literal>%r</> would
1143 typically be used in a warm-standby configuration
1144 (see <xref linkend="warm-standby">).
1145 Write <literal>%%</> to embed an actual <literal>%</> character
1146 in the command.
1147 </para>
1148 <para>
1149 If the command returns a non-zero exit status then a WARNING log
1150 message will be written and the database will proceed to start up
1151 anyway. An exception is that if the command was terminated by a
1152 signal, the database will not proceed with startup.
1153 </para>
1154 </listitem>
1155 </varlistentry>
1157 <varlistentry id="recovery-target-time" xreflabel="recovery_target_time">
1158 <term><varname>recovery_target_time</varname>
1159 (<type>timestamp</type>)
1160 </term>
1161 <listitem>
1162 <para>
1163 This parameter specifies the time stamp up to which recovery
1164 will proceed.
1165 At most one of <varname>recovery_target_time</> and
1166 <xref linkend="recovery-target-xid"> can be specified.
1167 The default is to recover to the end of the WAL log.
1168 The precise stopping point is also influenced by
1169 <xref linkend="recovery-target-inclusive">.
1170 </para>
1171 </listitem>
1172 </varlistentry>
1174 <varlistentry id="recovery-target-xid" xreflabel="recovery_target_xid">
1175 <term><varname>recovery_target_xid</varname> (<type>string</type>)</term>
1176 <listitem>
1177 <para>
1178 This parameter specifies the transaction ID up to which recovery
1179 will proceed. Keep in mind
1180 that while transaction IDs are assigned sequentially at transaction
1181 start, transactions can complete in a different numeric order.
1182 The transactions that will be recovered are those that committed
1183 before (and optionally including) the specified one.
1184 At most one of <varname>recovery_target_xid</> and
1185 <xref linkend="recovery-target-time"> can be specified.
1186 The default is to recover to the end of the WAL log.
1187 The precise stopping point is also influenced by
1188 <xref linkend="recovery-target-inclusive">.
1189 </para>
1190 </listitem>
1191 </varlistentry>
1193 <varlistentry id="recovery-target-inclusive"
1194 xreflabel="recovery_target_inclusive">
1195 <term><varname>recovery_target_inclusive</varname>
1196 (<type>boolean</type>)
1197 </term>
1198 <listitem>
1199 <para>
1200 Specifies whether we stop just after the specified recovery target
1201 (<literal>true</literal>), or just before the recovery target
1202 (<literal>false</literal>).
1203 Applies to both <xref linkend="recovery-target-time">
1204 and <xref linkend="recovery-target-xid">, whichever one is
1205 specified for this recovery. This indicates whether transactions
1206 having exactly the target commit time or ID, respectively, will
1207 be included in the recovery. Default is <literal>true</>.
1208 </para>
1209 </listitem>
1210 </varlistentry>
1212 <varlistentry id="recovery-target-timeline"
1213 xreflabel="recovery_target_timeline">
1214 <term><varname>recovery_target_timeline</varname>
1215 (<type>string</type>)
1216 </term>
1217 <listitem>
1218 <para>
1219 Specifies recovering into a particular timeline. The default is
1220 to recover along the same timeline that was current when the
1221 base backup was taken. You would only need to set this parameter
1222 in complex re-recovery situations, where you need to return to
1223 a state that itself was reached after a point-in-time recovery.
1224 See <xref linkend="backup-timelines"> for discussion.
1225 </para>
1226 </listitem>
1227 </varlistentry>
1229 </variablelist>
1231 </sect3>
1233 </sect2>
1235 <sect2 id="backup-timelines">
1236 <title>Timelines</title>
1238 <indexterm zone="backup">
1239 <primary>timelines</primary>
1240 </indexterm>
1242 <para>
1243 The ability to restore the database to a previous point in time creates
1244 some complexities that are akin to science-fiction stories about time
1245 travel and parallel universes. In the original history of the database,
1246 perhaps you dropped a critical table at 5:15PM on Tuesday evening, but
1247 didn't realize your mistake until Wednesday noon.
1248 Unfazed, you get out your backup, restore to the point-in-time 5:14PM
1249 Tuesday evening, and are up and running. In <emphasis>this</> history of
1250 the database universe, you never dropped the table at all. But suppose
1251 you later realize this wasn't such a great idea after all, and would like
1252 to return to sometime Wednesday morning in the original history.
1253 You won't be able
1254 to if, while your database was up-and-running, it overwrote some of the
1255 sequence of WAL segment files that led up to the time you now wish you
1256 could get back to. So you really want to distinguish the series of
1257 WAL records generated after you've done a point-in-time recovery from
1258 those that were generated in the original database history.
1259 </para>
1261 <para>
1262 To deal with these problems, <productname>PostgreSQL</> has a notion
1263 of <firstterm>timelines</>. Whenever an archive recovery is completed,
1264 a new timeline is created to identify the series of WAL records
1265 generated after that recovery. The timeline
1266 ID number is part of WAL segment file names, and so a new timeline does
1267 not overwrite the WAL data generated by previous timelines. It is
1268 in fact possible to archive many different timelines. While that might
1269 seem like a useless feature, it's often a lifesaver. Consider the
1270 situation where you aren't quite sure what point-in-time to recover to,
1271 and so have to do several point-in-time recoveries by trial and error
1272 until you find the best place to branch off from the old history. Without
1273 timelines this process would soon generate an unmanageable mess. With
1274 timelines, you can recover to <emphasis>any</> prior state, including
1275 states in timeline branches that you later abandoned.
1276 </para>
1278 <para>
1279 Each time a new timeline is created, <productname>PostgreSQL</> creates
1280 a <quote>timeline history</> file that shows which timeline it branched
1281 off from and when. These history files are necessary to allow the system
1282 to pick the right WAL segment files when recovering from an archive that
1283 contains multiple timelines. Therefore, they are archived into the WAL
1284 archive area just like WAL segment files. The history files are just
1285 small text files, so it's cheap and appropriate to keep them around
1286 indefinitely (unlike the segment files which are large). You can, if
1287 you like, add comments to a history file to make your own notes about
1288 how and why this particular timeline came to be. Such comments will be
1289 especially valuable when you have a thicket of different timelines as
1290 a result of experimentation.
1291 </para>
1293 <para>
1294 The default behavior of recovery is to recover along the same timeline
1295 that was current when the base backup was taken. If you want to recover
1296 into some child timeline (that is, you want to return to some state that
1297 was itself generated after a recovery attempt), you need to specify the
1298 target timeline ID in <filename>recovery.conf</>. You cannot recover into
1299 timelines that branched off earlier than the base backup.
1300 </para>
1301 </sect2>
1303 <sect2 id="backup-tips">
1304 <title>Tips and Examples</title>
1306 <para>
1307 Some tips for configuring continuous archiving are given here.
1308 </para>
1310 <sect3 id="backup-standalone">
1311 <title>Standalone hot backups</title>
1313 <para>
1314 It is possible to use <productname>PostgreSQL</>'s backup facilities to
1315 produce standalone hot backups. These are backups that cannot be used
1316 for point-in-time recovery, yet are typically much faster to backup and
1317 restore than <application>pg_dump</> dumps. (They are also much larger
1318 than <application>pg_dump</> dumps, so in some cases the speed advantage
1319 could be negated.)
1320 </para>
1322 <para>
1323 To prepare for standalone hot backups, set <varname>archive_mode</> to
1324 <literal>on</>, and set up an <varname>archive_command</> that performs
1325 archiving only when a <quote>switch file</> exists. For example:
1326 <programlisting>
1327 archive_command = 'test ! -f /var/lib/pgsql/backup_in_progress || cp -i %p /var/lib/pgsql/archive/%f &lt; /dev/null'
1328 </programlisting>
1329 This command will perform archiving when
1330 <filename>/var/lib/pgsql/backup_in_progress</> exists, and otherwise
1331 silently return zero exit status (allowing <productname>PostgreSQL</>
1332 to recycle the unwanted WAL file).
1333 </para>
1335 <para>
1336 With this preparation, a backup can be taken using a script like the
1337 following:
1338 <programlisting>
1339 touch /var/lib/pgsql/backup_in_progress
1340 psql -c "select pg_start_backup('hot_backup');"
1341 tar -cf /var/lib/pgsql/backup.tar /var/lib/pgsql/data/
1342 psql -c "select pg_stop_backup();"
1343 rm /var/lib/pgsql/backup_in_progress
1344 tar -rf /var/lib/pgsql/backup.tar /var/lib/pgsql/archive/
1345 </programlisting>
1346 The switch file <filename>/var/lib/pgsql/backup_in_progress</> is
1347 created first, enabling archiving of completed WAL files to occur.
1348 After the backup the switch file is removed. Archived WAL files are
1349 then added to the backup so that both base backup and all required
1350 WAL files are part of the same <application>tar</> file.
1351 Please remember to add error handling to your backup scripts.
1352 </para>
1354 <para>
1355 If archive storage size is a concern, use <application>pg_compresslog</>,
1356 <ulink url="http://pglesslog.projects.postgresql.org"></ulink>, to
1357 remove unnecessary <xref linkend="guc-full-page-writes"> and trailing
1358 space from the WAL files. You can then use
1359 <application>gzip</application> to further compress the output of
1360 <application>pg_compresslog</>:
1361 <programlisting>
1362 archive_command = 'pg_compresslog %p - | gzip &gt; /var/lib/pgsql/archive/%f'
1363 </programlisting>
1364 You will then need to use <application>gunzip</> and
1365 <application>pg_decompresslog</> during recovery:
1366 <programlisting>
1367 restore_command = 'gunzip &lt; /mnt/server/archivedir/%f | pg_decompresslog - %p'
1368 </programlisting>
1369 </para>
1370 </sect3>
1372 <sect3 id="backup-scripts">
1373 <title><varname>archive_command</varname> scripts</title>
1375 <para>
1376 Many people choose to use scripts to define their
1377 <varname>archive_command</varname>, so that their
1378 <filename>postgresql.conf</> entry looks very simple:
1379 <programlisting>
1380 archive_command = 'local_backup_script.sh'
1381 </programlisting>
1382 Using a separate script file is advisable any time you want to use
1383 more than a single command in the archiving process.
1384 This allows all complexity to be managed within the script, which
1385 can be written in a popular scripting language such as
1386 <application>bash</> or <application>perl</>.
1387 Any messages written to <literal>stderr</> from the script will appear
1388 in the database server log, allowing complex configurations to be
1389 diagnosed easily if they fail.
1390 </para>
1392 <para>
1393 Examples of requirements that might be solved within a script include:
1394 <itemizedlist>
1395 <listitem>
1396 <para>
1397 Copying data to secure off-site data storage
1398 </para>
1399 </listitem>
1400 <listitem>
1401 <para>
1402 Batching WAL files so that they are transferred every three hours,
1403 rather than one at a time
1404 </para>
1405 </listitem>
1406 <listitem>
1407 <para>
1408 Interfacing with other backup and recovery software
1409 </para>
1410 </listitem>
1411 <listitem>
1412 <para>
1413 Interfacing with monitoring software to report errors
1414 </para>
1415 </listitem>
1416 </itemizedlist>
1417 </para>
1418 </sect3>
1419 </sect2>
1421 <sect2 id="continuous-archiving-caveats">
1422 <title>Caveats</title>
1424 <para>
1425 At this writing, there are several limitations of the continuous archiving
1426 technique. These will probably be fixed in future releases:
1428 <itemizedlist>
1429 <listitem>
1430 <para>
1431 Operations on hash indexes are not presently WAL-logged, so
1432 replay will not update these indexes. The recommended workaround
1433 is to manually <xref linkend="sql-reindex" endterm="sql-reindex-title">
1434 each such index after completing a recovery operation.
1435 </para>
1436 </listitem>
1438 <listitem>
1439 <para>
1440 If a <xref linkend="sql-createdatabase" endterm="sql-createdatabase-title">
1441 command is executed while a base backup is being taken, and then
1442 the template database that the <command>CREATE DATABASE</> copied
1443 is modified while the base backup is still in progress, it is
1444 possible that recovery will cause those modifications to be
1445 propagated into the created database as well. This is of course
1446 undesirable. To avoid this risk, it is best not to modify any
1447 template databases while taking a base backup.
1448 </para>
1449 </listitem>
1451 <listitem>
1452 <para>
1453 <xref linkend="sql-createtablespace" endterm="sql-createtablespace-title">
1454 commands are WAL-logged with the literal absolute path, and will
1455 therefore be replayed as tablespace creations with the same
1456 absolute path. This might be undesirable if the log is being
1457 replayed on a different machine. It can be dangerous even if the
1458 log is being replayed on the same machine, but into a new data
1459 directory: the replay will still overwrite the contents of the
1460 original tablespace. To avoid potential gotchas of this sort,
1461 the best practice is to take a new base backup after creating or
1462 dropping tablespaces.
1463 </para>
1464 </listitem>
1465 </itemizedlist>
1466 </para>
1468 <para>
1469 It should also be noted that the default <acronym>WAL</acronym>
1470 format is fairly bulky since it includes many disk page snapshots.
1471 These page snapshots are designed to support crash recovery, since
1472 we might need to fix partially-written disk pages. Depending on
1473 your system hardware and software, the risk of partial writes might
1474 be small enough to ignore, in which case you can significantly
1475 reduce the total volume of archived logs by turning off page
1476 snapshots using the <xref linkend="guc-full-page-writes">
1477 parameter. (Read the notes and warnings in <xref linkend="wal">
1478 before you do so.) Turning off page snapshots does not prevent
1479 use of the logs for PITR operations. An area for future
1480 development is to compress archived WAL data by removing
1481 unnecessary page copies even when <varname>full_page_writes</> is
1482 on. In the meantime, administrators might wish to reduce the number
1483 of page snapshots included in WAL by increasing the checkpoint
1484 interval parameters as much as feasible.
1485 </para>
1486 </sect2>
1487 </sect1>
1489 <sect1 id="warm-standby">
1490 <title>Warm Standby Servers for High Availability</title>
1492 <indexterm zone="backup">
1493 <primary>warm standby</primary>
1494 </indexterm>
1496 <indexterm zone="backup">
1497 <primary>PITR standby</primary>
1498 </indexterm>
1500 <indexterm zone="backup">
1501 <primary>standby server</primary>
1502 </indexterm>
1504 <indexterm zone="backup">
1505 <primary>log shipping</primary>
1506 </indexterm>
1508 <indexterm zone="backup">
1509 <primary>witness server</primary>
1510 </indexterm>
1512 <indexterm zone="backup">
1513 <primary>STONITH</primary>
1514 </indexterm>
1516 <indexterm zone="backup">
1517 <primary>high availability</primary>
1518 </indexterm>
1520 <para>
1521 Continuous archiving can be used to create a <firstterm>high
1522 availability</> (HA) cluster configuration with one or more
1523 <firstterm>standby servers</> ready to take over operations if the
1524 primary server fails. This capability is widely referred to as
1525 <firstterm>warm standby</> or <firstterm>log shipping</>.
1526 </para>
1528 <para>
1529 The primary and standby server work together to provide this capability,
1530 though the servers are only loosely coupled. The primary server operates
1531 in continuous archiving mode, while each standby server operates in
1532 continuous recovery mode, reading the WAL files from the primary. No
1533 changes to the database tables are required to enable this capability,
1534 so it offers low administration overhead in comparison with some other
1535 replication approaches. This configuration also has relatively low
1536 performance impact on the primary server.
1537 </para>
1539 <para>
1540 Directly moving WAL records from one database server to another
1541 is typically described as log shipping. <productname>PostgreSQL</>
1542 implements file-based log shipping, which means that WAL records are
1543 transferred one file (WAL segment) at a time. WAL files (16MB) can be
1544 shipped easily and cheaply over any distance, whether it be to an
1545 adjacent system, another system on the same site or another system on
1546 the far side of the globe. The bandwidth required for this technique
1547 varies according to the transaction rate of the primary server.
1548 Record-based log shipping is also possible with custom-developed
1549 procedures, as discussed in <xref linkend="warm-standby-record">.
1550 </para>
1552 <para>
1553 It should be noted that the log shipping is asynchronous, i.e., the WAL
1554 records are shipped after transaction commit. As a result there is a
1555 window for data loss should the primary server suffer a catastrophic
1556 failure: transactions not yet shipped will be lost. The length of the
1557 window of data loss can be limited by use of the
1558 <varname>archive_timeout</varname> parameter, which can be set as low
1559 as a few seconds if required. However such low settings will
1560 substantially increase the bandwidth requirements for file shipping.
1561 If you need a window of less than a minute or so, it's probably better
1562 to look into record-based log shipping.
1563 </para>
1565 <para>
1566 The standby server is not available for access, since it is continually
1567 performing recovery processing. Recovery performance is sufficiently
1568 good that the standby will typically be only moments away from full
1569 availability once it has been activated. As a result, we refer to this
1570 capability as a warm standby configuration that offers high
1571 availability. Restoring a server from an archived base backup and
1572 rollforward will take considerably longer, so that technique only
1573 offers a solution for disaster recovery, not high availability.
1574 </para>
1576 <sect2 id="warm-standby-planning">
1577 <title>Planning</title>
1579 <para>
1580 It is usually wise to create the primary and standby servers
1581 so that they are as similar as possible, at least from the
1582 perspective of the database server. In particular, the path names
1583 associated with tablespaces will be passed across as-is, so both
1584 primary and standby servers must have the same mount paths for
1585 tablespaces if that feature is used. Keep in mind that if
1586 <xref linkend="sql-createtablespace" endterm="sql-createtablespace-title">
1587 is executed on the primary, any new mount point needed for it must
1588 be created on both the primary and all standby servers before the command
1589 is executed. Hardware need not be exactly the same, but experience shows
1590 that maintaining two identical systems is easier than maintaining two
1591 dissimilar ones over the lifetime of the application and system.
1592 In any case the hardware architecture must be the same &mdash; shipping
1593 from, say, a 32-bit to a 64-bit system will not work.
1594 </para>
1596 <para>
1597 In general, log shipping between servers running different major
1598 <productname>PostgreSQL</> release
1599 levels will not be possible. It is the policy of the PostgreSQL Global
1600 Development Group not to make changes to disk formats during minor release
1601 upgrades, so it is likely that running different minor release levels
1602 on primary and standby servers will work successfully. However, no
1603 formal support for that is offered and you are advised to keep primary
1604 and standby servers at the same release level as much as possible.
1605 When updating to a new minor release, the safest policy is to update
1606 the standby servers first &mdash; a new minor release is more likely
1607 to be able to read WAL files from a previous minor release than vice
1608 versa.
1609 </para>
1611 <para>
1612 There is no special mode required to enable a standby server. The
1613 operations that occur on both primary and standby servers are entirely
1614 normal continuous archiving and recovery tasks. The only point of
1615 contact between the two database servers is the archive of WAL files
1616 that both share: primary writing to the archive, standby reading from
1617 the archive. Care must be taken to ensure that WAL archives for separate
1618 primary servers do not become mixed together or confused. The archive
1619 need not be large, if it is only required for the standby operation.
1620 </para>
1622 <para>
1623 The magic that makes the two loosely coupled servers work together is
1624 simply a <varname>restore_command</> used on the standby that,
1625 when asked for the next WAL file, waits for it to become available from
1626 the primary. The <varname>restore_command</> is specified in the
1627 <filename>recovery.conf</> file on the standby server. Normal recovery
1628 processing would request a file from the WAL archive, reporting failure
1629 if the file was unavailable. For standby processing it is normal for
1630 the next WAL file to be unavailable, so we must be patient and wait for
1631 it to appear. For files ending in <literal>.backup</> or
1632 <literal>.history</> there is no need to wait, and a non-zero return
1633 code must be returned. A waiting <varname>restore_command</> can be
1634 written as a custom script that loops after polling for the existence of
1635 the next WAL file. There must also be some way to trigger failover, which
1636 should interrupt the <varname>restore_command</>, break the loop and
1637 return a file-not-found error to the standby server. This ends recovery
1638 and the standby will then come up as a normal server.
1639 </para>
1641 <para>
1642 Pseudocode for a suitable <varname>restore_command</> is:
1643 <programlisting>
1644 triggered = false;
1645 while (!NextWALFileReady() &amp;&amp; !triggered)
1647 sleep(100000L); /* wait for ~0.1 sec */
1648 if (CheckForExternalTrigger())
1649 triggered = true;
1651 if (!triggered)
1652 CopyWALFileForRecovery();
1653 </programlisting>
1654 </para>
1656 <para>
1657 A working example of a waiting <varname>restore_command</> is provided
1658 as a <filename>contrib</> module named <application>pg_standby</>. It
1659 should be used as a reference on how to correctly implement the logic
1660 described above. It can also be extended as needed to support specific
1661 configurations or environments.
1662 </para>
1664 <para>
1665 <productname>PostgreSQL</productname> does not provide the system
1666 software required to identify a failure on the primary and notify
1667 the standby system and then the standby database server. Many such
1668 tools exist and are well integrated with other aspects required for
1669 successful failover, such as IP address migration.
1670 </para>
1672 <para>
1673 The means for triggering failover is an important part of planning and
1674 design. The <varname>restore_command</> is executed in full once
1675 for each WAL file. The process running the <varname>restore_command</>
1676 is therefore created and dies for each file, so there is no daemon
1677 or server process and so we cannot use signals and a signal
1678 handler. A more permanent notification is required to trigger the
1679 failover. It is possible to use a simple timeout facility,
1680 especially if used in conjunction with a known
1681 <varname>archive_timeout</> setting on the primary. This is
1682 somewhat error prone since a network problem or busy primary server might
1683 be sufficient to initiate failover. A notification mechanism such
1684 as the explicit creation of a trigger file is less error prone, if
1685 this can be arranged.
1686 </para>
1688 <para>
1689 The size of the WAL archive can be minimized by using the <literal>%r</>
1690 option of the <varname>restore_command</>. This option specifies the
1691 last archive file name that needs to be kept to allow the recovery to
1692 restart correctly. This can be used to truncate the archive once
1693 files are no longer required, if the archive is writable from the
1694 standby server.
1695 </para>
1696 </sect2>
1698 <sect2 id="warm-standby-config">
1699 <title>Implementation</title>
1701 <para>
1702 The short procedure for configuring a standby server is as follows. For
1703 full details of each step, refer to previous sections as noted.
1704 <orderedlist>
1705 <listitem>
1706 <para>
1707 Set up primary and standby systems as near identically as
1708 possible, including two identical copies of
1709 <productname>PostgreSQL</> at the same release level.
1710 </para>
1711 </listitem>
1712 <listitem>
1713 <para>
1714 Set up continuous archiving from the primary to a WAL archive located
1715 in a directory on the standby server. Ensure that
1716 <xref linkend="guc-archive-mode">,
1717 <xref linkend="guc-archive-command"> and
1718 <xref linkend="guc-archive-timeout">
1719 are set appropriately on the primary
1720 (see <xref linkend="backup-archiving-wal">).
1721 </para>
1722 </listitem>
1723 <listitem>
1724 <para>
1725 Make a base backup of the primary server (see <xref
1726 linkend="backup-base-backup">), and load this data onto the standby.
1727 </para>
1728 </listitem>
1729 <listitem>
1730 <para>
1731 Begin recovery on the standby server from the local WAL
1732 archive, using a <filename>recovery.conf</> that specifies a
1733 <varname>restore_command</> that waits as described
1734 previously (see <xref linkend="backup-pitr-recovery">).
1735 </para>
1736 </listitem>
1737 </orderedlist>
1738 </para>
1740 <para>
1741 Recovery treats the WAL archive as read-only, so once a WAL file has
1742 been copied to the standby system it can be copied to tape at the same
1743 time as it is being read by the standby database server.
1744 Thus, running a standby server for high availability can be performed at
1745 the same time as files are stored for longer term disaster recovery
1746 purposes.
1747 </para>
1749 <para>
1750 For testing purposes, it is possible to run both primary and standby
1751 servers on the same system. This does not provide any worthwhile
1752 improvement in server robustness, nor would it be described as HA.
1753 </para>
1754 </sect2>
1756 <sect2 id="warm-standby-failover">
1757 <title>Failover</title>
1759 <para>
1760 If the primary server fails then the standby server should begin
1761 failover procedures.
1762 </para>
1764 <para>
1765 If the standby server fails then no failover need take place. If the
1766 standby server can be restarted, even some time later, then the recovery
1767 process can also be immediately restarted, taking advantage of
1768 restartable recovery. If the standby server cannot be restarted, then a
1769 full new standby server instance should be created.
1770 </para>
1772 <para>
1773 If the primary server fails and then immediately restarts, you must have
1774 a mechanism for informing it that it is no longer the primary. This is
1775 sometimes known as STONITH (Shoot the Other Node In The Head), which is
1776 necessary to avoid situations where both systems think they are the
1777 primary, which will lead to confusion and ultimately data loss.
1778 </para>
1780 <para>
1781 Many failover systems use just two systems, the primary and the standby,
1782 connected by some kind of heartbeat mechanism to continually verify the
1783 connectivity between the two and the viability of the primary. It is
1784 also possible to use a third system (called a witness server) to prevent
1785 some cases of inappropriate failover, but the additional complexity
1786 might not be worthwhile unless it is set up with sufficient care and
1787 rigorous testing.
1788 </para>
1790 <para>
1791 Once failover to the standby occurs, we have only a
1792 single server in operation. This is known as a degenerate state.
1793 The former standby is now the primary, but the former primary is down
1794 and might stay down. To return to normal operation we must
1795 fully recreate a standby server,
1796 either on the former primary system when it comes up, or on a third,
1797 possibly new, system. Once complete the primary and standby can be
1798 considered to have switched roles. Some people choose to use a third
1799 server to provide backup to the new primary until the new standby
1800 server is recreated,
1801 though clearly this complicates the system configuration and
1802 operational processes.
1803 </para>
1805 <para>
1806 So, switching from primary to standby server can be fast but requires
1807 some time to re-prepare the failover cluster. Regular switching from
1808 primary to standby is useful, since it allows regular downtime on
1809 each system for maintenance. This also serves as a test of the
1810 failover mechanism to ensure that it will really work when you need it.
1811 Written administration procedures are advised.
1812 </para>
1813 </sect2>
1815 <sect2 id="warm-standby-record">
1816 <title>Record-based Log Shipping</title>
1818 <para>
1819 <productname>PostgreSQL</productname> directly supports file-based
1820 log shipping as described above. It is also possible to implement
1821 record-based log shipping, though this requires custom development.
1822 </para>
1824 <para>
1825 An external program can call the <function>pg_xlogfile_name_offset()</>
1826 function (see <xref linkend="functions-admin">)
1827 to find out the file name and the exact byte offset within it of
1828 the current end of WAL. It can then access the WAL file directly
1829 and copy the data from the last known end of WAL through the current end
1830 over to the standby server(s). With this approach, the window for data
1831 loss is the polling cycle time of the copying program, which can be very
1832 small, but there is no wasted bandwidth from forcing partially-used
1833 segment files to be archived. Note that the standby servers'
1834 <varname>restore_command</> scripts still deal in whole WAL files,
1835 so the incrementally copied data is not ordinarily made available to
1836 the standby servers. It is of use only when the primary dies &mdash;
1837 then the last partial WAL file is fed to the standby before allowing
1838 it to come up. So correct implementation of this process requires
1839 cooperation of the <varname>restore_command</> script with the data
1840 copying program.
1841 </para>
1842 </sect2>
1844 <sect2 id="backup-incremental-updated">
1845 <title>Incrementally Updated Backups</title>
1847 <indexterm zone="backup">
1848 <primary>incrementally updated backups</primary>
1849 </indexterm>
1851 <indexterm zone="backup">
1852 <primary>change accumulation</primary>
1853 </indexterm>
1855 <para>
1856 In a warm standby configuration, it is possible to offload the expense of
1857 taking periodic base backups from the primary server; instead base backups
1858 can be made by backing
1859 up a standby server's files. This concept is generally known as
1860 incrementally updated backups, log change accumulation, or more simply,
1861 change accumulation.
1862 </para>
1864 <para>
1865 If we take a backup of the standby server's data directory while it is processing
1866 logs shipped from the primary, we will be able to reload that data and
1867 restart the standby's recovery process from the last restart point.
1868 We no longer need to keep WAL files from before the restart point.
1869 If we need to recover, it will be faster to recover from the incrementally
1870 updated backup than from the original base backup.
1871 </para>
1873 <para>
1874 Since the standby server is not <quote>live</>, it is not possible to
1875 use <function>pg_start_backup()</> and <function>pg_stop_backup()</>
1876 to manage the backup process; it will be up to you to determine how
1877 far back you need to keep WAL segment files to have a recoverable
1878 backup. You can do this by running <application>pg_controldata</>
1879 on the standby server to inspect the control file and determine the
1880 current checkpoint WAL location, or by using the
1881 <varname>log_checkpoints</> option to print values to the server log.
1882 </para>
1883 </sect2>
1884 </sect1>
1886 <sect1 id="migration">
1887 <title>Migration Between Releases</title>
1889 <indexterm zone="migration">
1890 <primary>upgrading</primary>
1891 </indexterm>
1893 <indexterm zone="migration">
1894 <primary>version</primary>
1895 <secondary>compatibility</secondary>
1896 </indexterm>
1898 <para>
1899 This section discusses how to migrate your database data from one
1900 <productname>PostgreSQL</> release to a newer one.
1901 The software installation procedure <foreignphrase>per se</> is not the
1902 subject of this section; those details are in <xref linkend="installation">.
1903 </para>
1905 <para>
1906 As a general rule, the internal data storage format is subject to
1907 change between major releases of <productname>PostgreSQL</> (where
1908 the number after the first dot changes). This does not apply to
1909 different minor releases under the same major release (where the
1910 number after the second dot changes); these always have compatible
1911 storage formats. For example, releases 8.1.1, 8.2.3, and 8.3 are
1912 not compatible, whereas 8.2.3 and 8.2.4 are. When you update
1913 between compatible versions, you can simply replace the executables
1914 and reuse the data directory on disk. Otherwise you need to back
1915 up your data and restore it on the new server. This has to be done
1916 using <application>pg_dump</>; file system level backup methods
1917 obviously won't work. There are checks in place that prevent you
1918 from using a data directory with an incompatible version of
1919 <productname>PostgreSQL</productname>, so no great harm can be done by
1920 trying to start the wrong server version on a data directory.
1921 </para>
1923 <para>
1924 It is recommended that you use the <application>pg_dump</> and
1925 <application>pg_dumpall</> programs from the newer version of
1926 <productname>PostgreSQL</>, to take advantage of any enhancements
1927 that might have been made in these programs. Current releases of the
1928 dump programs can read data from any server version back to 7.0.
1929 </para>
1931 <para>
1932 The least downtime can be achieved by installing the new server in
1933 a different directory and running both the old and the new servers
1934 in parallel, on different ports. Then you can use something like:
1936 <programlisting>
1937 pg_dumpall -p 5432 | psql -d postgres -p 6543
1938 </programlisting>
1940 to transfer your data. Or use an intermediate file if you want.
1941 Then you can shut down the old server and start the new server at
1942 the port the old one was running at. You should make sure that the
1943 old database is not updated after you begin to run
1944 <application>pg_dumpall</>, otherwise you will lose that data. See <xref
1945 linkend="client-authentication"> for information on how to prohibit
1946 access.
1947 </para>
1949 <para>
1950 It is also possible to use replication methods, such as
1951 <productname>Slony</>, to create a slave server with the updated version of
1952 <productname>PostgreSQL</>. The slave can be on the same computer or
1953 a different computer. Once it has synced up with the master server
1954 (running the older version of <productname>PostgreSQL</>), you can
1955 switch masters and make the slave the master and shut down the older
1956 database instance. Such a switch-over results in only several seconds
1957 of downtime for an upgrade.
1958 </para>
1960 <para>
1961 If you cannot or do not want to run two servers in parallel, you can
1962 do the backup step before installing the new version, bring down
1963 the server, move the old version out of the way, install the new
1964 version, start the new server, and restore the data. For example:
1966 <programlisting>
1967 pg_dumpall &gt; backup
1968 pg_ctl stop
1969 mv /usr/local/pgsql /usr/local/pgsql.old
1970 cd ~/postgresql-&version;
1971 gmake install
1972 initdb -D /usr/local/pgsql/data
1973 postgres -D /usr/local/pgsql/data
1974 psql -f backup postgres
1975 </programlisting>
1977 See <xref linkend="runtime"> about ways to start and stop the
1978 server and other details. The installation instructions will advise
1979 you of strategic places to perform these steps.
1980 </para>
1982 <note>
1983 <para>
1984 When you <quote>move the old installation out of the way</quote>
1985 it might no longer be perfectly usable. Some of the executable programs
1986 contain absolute paths to various installed programs and data files.
1987 This is usually not a big problem, but if you plan on using two
1988 installations in parallel for a while you should assign them
1989 different installation directories at build time. (This problem
1990 is rectified in <productname>PostgreSQL</> 8.0 and later, so long
1991 as you move all subdirectories containing installed files together;
1992 for example if <filename>/usr/local/postgres/bin/</> goes to
1993 <filename>/usr/local/postgres.old/bin/</>, then
1994 <filename>/usr/local/postgres/share/</> must go to
1995 <filename>/usr/local/postgres.old/share/</>. In pre-8.0 releases
1996 moving an installation like this will not work.)
1997 </para>
1998 </note>
2000 <para>
2001 In practice you probably want to test your client applications on the
2002 new version before switching over completely. This is another reason
2003 for setting up concurrent installations of old and new versions. When
2004 testing a <productname>PostgreSQL</> major upgrade, consider the
2005 following categories of possible changes:
2006 </para>
2008 <variablelist>
2010 <varlistentry>
2011 <term>Administration</term>
2012 <listitem>
2013 <para>
2014 The capabilities available for administrators to monitor and control
2015 the server often change and improve in each major release.
2016 </para>
2017 </listitem>
2018 </varlistentry>
2020 <varlistentry>
2021 <term>SQL</term>
2022 <listitem>
2023 <para>
2024 Typically this includes new SQL command capabilities and not changes
2025 in behavior, unless specifically mentioned in the release notes.
2026 </para>
2027 </listitem>
2028 </varlistentry>
2030 <varlistentry>
2031 <term>Library API</term>
2032 <listitem>
2033 <para>
2034 Typically libraries like <application>libpq</> only add new
2035 functionality, again unless mentioned in the release notes.
2036 </para>
2037 </listitem>
2038 </varlistentry>
2040 <varlistentry>
2041 <term>System Catalogs</term>
2042 <listitem>
2043 <para>
2044 System catalog changes usually only affect database management tools.
2045 </para>
2046 </listitem>
2047 </varlistentry>
2049 <varlistentry>
2050 <term>Server C-language API</term>
2051 <listitem>
2052 <para>
2053 This involved changes in the backend function API, which is written
2054 in the C programming language. Such changes effect code that
2055 references backend functions deep inside the server.
2056 </para>
2057 </listitem>
2058 </varlistentry>
2060 </variablelist>
2062 </sect1>
2063 </chapter>