PostgreSQL pg_dump and pg_restore Guide
Table of Contents
___________________________________________________________________________________________________
Backup:
0. pg_dump / pg_restore –help
1. Backup Output Formats
2. Full Database Backup
3. Schema Level Backup
4. Table Level Backup
5. Object Level Backup (PostgreSQL v17 Feature)
Restore:
6. Pre-requisites for Restore
7. Full Database Restore
8. Schema Level Restore
- A. Restore from Own Table’s Backup
- B. Restore Table Data-Only from Schema Backup
- C. Restore Table from Schema Backup
- D. Restore Table with -n and -t Options
- E. Restore Using Plain SQL File (COPY-based)
___________________________________________________________________________________________________
0. pg_dump/pg_restore –help
Click to expand pg_dump –help
[postgres@pg17 ~]$ pg_dump --help pg_dump dumps a database as a text file or to other formats. Usage: pg_dump [OPTION]... [DBNAME] General options: -f, --file=FILENAME output file or directory name -F, --format=c|d|t|p output file format (custom, directory, tar, plain text (default)) -j, --jobs=NUM use this many parallel jobs to dump -v, --verbose verbose mode -V, --version output version information, then exit -Z, --compress=0-9 compression level for compressed formats --lock-wait-timeout=TIMEOUT fail after waiting TIMEOUT for a table lock --no-sync do not wait for changes to be written safely to disk -?, --help show this help, then exit Options controlling the output content: -a, --data-only dump only the data, not the schema -b, --blobs include large objects in dump -B, --no-blobs exclude large objects in dump -c, --clean clean (drop) database objects before recreating -C, --create include commands to create database in dump -e, --extension=PATTERN dump the specified extension(s) only -E, --encoding=ENCODING dump the data in encoding ENCODING -n, --schema=PATTERN dump the specified schema(s) only -N, --exclude-schema=PATTERN do NOT dump the specified schema(s) -O, --no-owner skip restoration of object ownership in plain-text format -s, --schema-only dump only the schema, no data -S, --superuser=NAME superuser user name to use in plain-text format -t, --table=PATTERN dump the specified table(s) only -T, --exclude-table=PATTERN do NOT dump the specified table(s) -x, --no-privileges do not dump privileges (grant/revoke) --binary-upgrade for use by upgrade utilities only --column-inserts dump data as INSERT commands with column names --disable-dollar-quoting disable dollar quoting, use SQL standard quoting --disable-triggers disable triggers during data-only restore --enable-row-security enable row security (dump only content user has access to) --exclude-table-data=PATTERN do NOT dump data for the specified table(s) --extra-float-digits=NUM override default setting for extra_float_digits --if-exists use IF EXISTS when dropping objects --include-foreign-data=PATTERN include data of foreign tables on foreign servers matching PATTERN --inserts dump data as INSERT commands, rather than COPY --load-via-partition-root load partitions via the root table --no-comments do not dump comments --no-publications do not dump publications --no-security-labels do not dump security label assignments --no-subscriptions do not dump subscriptions --no-table-access-method do not dump table access methods --no-tablespaces do not dump tablespace assignments --no-toast-compression do not dump TOAST compression methods --no-unlogged-table-data do not dump unlogged table data --on-conflict-do-nothing add ON CONFLICT DO NOTHING to INSERT commands --quote-all-identifiers quote all identifiers, even if not key words --rows-per-insert=NROWS number of rows per INSERT; implies --inserts --section=SECTION dump named section (pre-data, data, or post-data) --serializable-deferrable wait until the dump can run without anomalies --snapshot=SNAPSHOT use given snapshot for the dump --strict-names require table and/or schema include patterns to match at least one entity each --use-set-session-authorization use SET SESSION AUTHORIZATION commands instead of ALTER OWNER commands to set ownership Connection options: -d, --dbname=DBNAME database to dump -h, --host=HOSTNAME database server host or socket directory -p, --port=PORT database server port number -U, --username=NAME connect as specified database user -w, --no-password never prompt for password -W, --password force password prompt (should happen automatically) --role=ROLENAME do SET ROLE before dump If no database name is supplied, then the PGDATABASE environment variable value is used. Report bugs to <pgsql-bugs@lists.postgresql.org>. PostgreSQL home page: <https://www.postgresql.org/> [postgres@pg17 ~]$
Click to expand pg_restore –help
[postgres@pg17 ~]$ pg_restore --help pg_restore restores a PostgreSQL database from an archive created by pg_dump. Usage: pg_restore [OPTION]... [FILE] General options: -d, --dbname=NAME connect to database name -f, --file=FILENAME output file name (- for stdout) -F, --format=c|d|t backup file format (should be automatic) -l, --list print summarized TOC of the archive -v, --verbose verbose mode -V, --version output version information, then exit -?, --help show this help, then exit Options controlling the restore: -a, --data-only restore only the data, no schema -c, --clean clean (drop) database objects before recreating -C, --create create the target database -e, --exit-on-error exit on error, default is to continue -I, --index=NAME restore named index -j, --jobs=NUM use this many parallel jobs to restore -L, --use-list=FILENAME use table of contents from this file for selecting/ordering output -n, --schema=NAME restore only objects in this schema -N, --exclude-schema=NAME do not restore objects in this schema -O, --no-owner skip restoration of object ownership -P, --function=NAME(args) restore named function -s, --schema-only restore only the schema, no data -S, --superuser=NAME superuser user name to use for disabling triggers -t, --table=NAME restore named relation (table, view, etc.) -T, --trigger=NAME restore named trigger -x, --no-privileges skip restoration of access privileges (grant/revoke) -1, --single-transaction restore as a single transaction --disable-triggers disable triggers during data-only restore --enable-row-security enable row security --if-exists use IF EXISTS when dropping objects --no-comments do not restore comments --no-data-for-failed-tables do not restore data of tables that could not be created --no-publications do not restore publications --no-security-labels do not restore security labels --no-subscriptions do not restore subscriptions --no-table-access-method do not restore table access methods --no-tablespaces do not restore tablespace assignments --section=SECTION restore named section (pre-data, data, or post-data) --strict-names require table and/or schema include patterns to match at least one entity each --use-set-session-authorization use SET SESSION AUTHORIZATION commands instead of ALTER OWNER commands to set ownership Connection options: -h, --host=HOSTNAME database server host or socket directory -p, --port=PORT database server port number -U, --username=NAME connect as specified database user -w, --no-password never prompt for password -W, --password force password prompt (should happen automatically) --role=ROLENAME do SET ROLE before restore The options -I, -n, -N, -P, -t, -T, and --section can be combined and specified multiple times to select multiple objects. If no input file name is supplied, then standard input is used. Report bugs to <pgsql-bugs@lists.postgresql.org>. PostgreSQL home page: <https://www.postgresql.org/> [postgres@pg17 ~]$
1. Backup Output Formats
A. Plain Text Format # Using -Fp explicitly: pg_dump -U postgres -d your_db_name -Fp -f /path/to/your_db.sql # Shell redirect pg_dump -U postgres -d your_db_name > /path/to/your_db.sql B. Tar Format pg_dump -U postgres -d your_db_name -Ft -f /path/to/your_db.tar C. Directory Format and Parallel Backup -- Parallel backup is only supported with -Fd -- pg_dump will create the directory if it doesn't exist. # Without parallelism pg_dump -U postgres -d your_db_name -Fd -f /path/to/backup_dir/ # With parallelism pg_dump -U postgres -d your_db_name -Fd -j8 -f /path/to/backup_dir/ D. Custom Format (Compressed binary format by default) pg_dump -U postgres -d your_db_name -Fc -f /path/to/your_db.dump
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -v > /pgBackup/pgsql15/backup/blpua/database_blpua_full.sql 2> /pgBackup/pgsql15/backup/blpua/log/database_blpua_full.log & -- OR -- [postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -v -Fp -f /pgBackup/pgsql15/backup/blpua/database_blpua_full1.sql > /pgBackup/pgsql15/backup/blpua/log/database_blpua_full1.log 2>&1 & -- OR -- [postgres@pg17 ~]$ pg_dump -U postgres -d blpua | split -b 1G - /pgBackup/pgsql15/backup/blpua/database_blpua_split.dmp [postgres@pg17 ~]$ [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/database_blpua_s* -rw-r--r--. 1 postgres postgres 1.0G Sep 30 11:03 /pgBackup/pgsql15/backup/blpua/database_blpua_split.dmpaa -rw-r--r--. 1 postgres postgres 650M Sep 30 11:03 /pgBackup/pgsql15/backup/blpua/database_blpua_split.dmpab [postgres@pg17 ~]$ -- OR -- [postgres@pg17 ~]$ nohup sh -c "pg_dump -U postgres -d blpua -v | gzip > /pgBackup/pgsql15/backup/blpua/database_blpua.gz" > /pgBackup/pgsql15/backup/blpua/log/database_blpua.log 2>&1 & -- OR -- [postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -v > /pgBackup/pgsql15/backup/blpua/database_blpua.sql 2> /pgBackup/pgsql15/backup/blpua/log/database_blpua.log & gzip /pgBackup/pgsql15/backup/blpua/database_blpua.sql
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -v -Ft -f /pgBackup/pgsql15/backup/blpua/database_blpua.tar > /pgBackup/pgsql15/backup/blpua/log/blpua_tar_dump.log 2>&1 &
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -v -Fd -j4 -f /pgBackup/pgsql15/backup/blpua_dir > /pgBackup/pgsql15/backup/blpua/log/blpua_dump.log 2>&1 &
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -Fc -v -f /pgBackup/pgsql15/backup/blpua/database_blpua_$(date +%Y_%m_%d).dmp > /pgBackup/pgsql15/backup/blpua/log/database_blpua_$(date +%Y_%m_%d).log 2>&1 & [postgres@pg17 ~]$ [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/database_blpua*.dmp -rw-r--r--. 1 postgres postgres 402M Sep 29 04:58 /pgBackup/pgsql15/backup/blpua/database_blpua_2025_09_29.dmp [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/log/database_blpua*.log -rw-r--r--. 1 postgres postgres 2.5K Sep 29 04:58 /pgBackup/pgsql15/backup/blpua/log/database_blpua_2025_09_29.log [postgres@pg17 ~]$
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -n blp -Fc -v -f /pgBackup/pgsql15/backup/blpua/schema_blp_blpua_$(date +%Y_%m_%d).dmp > /pgBackup/pgsql15/backup/blpua/log/schema_blp_blpua_$(date +%Y_%m_%d).log 2>&1 & [1] 5472 [postgres@pg17 ~]$ [postgres@pg17 ~]$ jobs -l [1]+ 5472 Running nohup pg_dump -U postgres -d blpua -n blp -Fc -v -f /pgBackup/pgsql15/backup/blpua/schema_blp_blpua_$(date +%Y_%m_%d).dmp > /pgBackup/pgsql15/backup/blpua/log/schema_blp_blpua_$(date +%Y_%m_%d).log 2>&1 & [postgres@pg17 ~]$ [postgres@pg17 ~]$ jobs -l [1]+ 5472 Done nohup pg_dump -U postgres -d blpua -n blp -Fc -v -f /pgBackup/pgsql15/backup/blpua/schema_blp_blpua_$(date +%Y_%m_%d).dmp > /pgBackup/pgsql15/backup/blpua/log/schema_blp_blpua_$(date +%Y_%m_%d).log 2>&1 [postgres@pg17 ~]$ [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/schema_blp_blpua* -rw-r--r--. 1 postgres postgres 402M Sep 30 02:09 /pgBackup/pgsql15/backup/blpua/schema_blp_blpua_2025_09_30.dmp [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/log/schema_blp_blpua* -rw-r--r--. 1 postgres postgres 2.5K Sep 30 02:09 /pgBackup/pgsql15/backup/blpua/log/schema_blp_blpua_2025_09_30.log [postgres@pg17 ~]$
[postgres@pg17 ~]$ nohup pg_dump -U postgres -d blpua -t blp.employees -Fc -v -f /pgBackup/pgsql15/backup/blpua/table_blp_employees_$(date +%Y_%m_%d).dmp > /pgBackup/pgsql15/backup/blpua/log/table_blp_employees_$(date +%Y_%m_%d).log 2>&1 & [1] 5652 [postgres@pg17 ~]$ [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/table_blp_employees_* -rw-r--r--. 1 postgres postgres 62M Sep 30 02:22 /pgBackup/pgsql15/backup/blpua/table_blp_employees_2025_09_30.dmp [postgres@pg17 ~]$ ls -lrth /pgBackup/pgsql15/backup/blpua/log/table_blp_employees_* -rw-r--r--. 1 postgres postgres 2.0K Sep 30 02:22 /pgBackup/pgsql15/backup/blpua/log/table_blp_employees_2025_09_30.log [postgres@pg17 ~]$
5. Object Level Backup (PostgreSQL v17 Feature)
++ filter is only for pg_dump, not pg_restore [postgres@lxicbpgdsgv01 ~]$ cat include_tables.par include table demo.table_1 include table demo.table_2 include table demo.table_3 [postgres@lxicbpgdsgv01 ~]$ [postgres@lxicbpgdsgv01 ~]$ pg_dump -d testdb_source --filter=include_tables.par > include_tables.sql [postgres@lxicbpgdsgv01 ~]$ ls -lrth include_tables.sql -rw-r--r--. 1 postgres postgres 4.5K Sep 30 22:19 include_tables.sql [postgres@lxicbpgdsgv01 ~]$ [postgres@lxicbpgdsgv01 ~]$ cat include_tables.sql | grep -i "CREATE TABLE" CREATE TABLE demo.table_1 ( CREATE TABLE demo.table_2 ( CREATE TABLE demo.table_3 ( [postgres@lxicbpgdsgv01 ~]$ [postgres@lxicbpgdsgv01 ~]$ cat exclude_tables.par exclude table demo.table_1 exclude table demo.table_2 exclude table demo.table_3 [postgres@lxicbpgdsgv01 ~]$ [postgres@lxicbpgdsgv01 ~]$ pg_dump -d testdb_source --filter=exclude_tables.par > exclude_tables.sql [postgres@lxicbpgdsgv01 ~]$ ls -ltr exclude_tables.sql -rw-r--r--. 1 postgres postgres 10931 Sep 30 22:23 exclude_tables.sql [postgres@lxicbpgdsgv01 ~]$ [postgres@lxicbpgdsgv01 ~]$ cat exclude_tables.sql | grep -i "CREATE TABLE" CREATE TABLE demo.table_10 ( CREATE TABLE demo.table_4 ( CREATE TABLE demo.table_5 ( CREATE TABLE demo.table_6 ( CREATE TABLE demo.table_7 ( CREATE TABLE demo.table_8 ( CREATE TABLE demo.table_9 ( [postgres@lxicbpgdsgv01 ~]$
postgres=# CREATE TABLESPACE TEST_TB LOCATION '/pgTb/pgsql15/test'; CREATE TABLESPACE postgres=# CREATE TABLESPACE TEST_IX LOCATION '/pgIx/pgsql15/test'; CREATE TABLESPACE postgres=# postgres=# CREATE DATABASE TEST TABLESPACE TEST_TB; CREATE DATABASE postgres=# [postgres@pg17 blpua]$ scp *.dmp postgres@192.168.2.32:/pgBackup/pgsql15/backup/test postgres@192.168.2.32's password: database_blpua_2025_09_29.dmp 100% 402MB 39.9MB/s 00:10 schema_blp_blpua_2025_09_30.dmp 100% 402MB 43.8MB/s 00:09 table_blp_employees_2025_09_30.dmp 100% 61MB 47.0MB/s 00:01 [postgres@pg17 blpua]$
++ The source database uses two custom tablespaces: blpua_tbs01 and blpua_ixtbs01. ++ On the target system, I have two different tablespaces: test_tb and test_ix. ++ Unlike Oracle, PostgreSQL does not provide a direct equivalent of REMAP_TABLESPACE. ++ Therefore, to simplify the restore and ensure all objects are placed into the default tablespace (test_tb). ++ Using --no-owner --no-tablespaces in pg_restore — even if not specified, data still gets written to the default database tablespace. These options just help avoid errors in the log. ++ This ensures that all objects are restored to the default tablespace of the target database, regardless of their original tablespace assignments. ++ Later, we can move all indexes to the desired target tablespace using the ALTER INDEX ... SET TABLESPACE command. postgres=# \c test You are now connected to database "test" as user "postgres". test=# ALTER INDEX blp.idx_employee_name SET TABLESPACE test_ix; <-- This command physically relocates the index to the test_ix tablespace. ALTER INDEX test=# [postgres@lxtrdpgdsgv01 ~]$ nohup pg_restore -U postgres -d test --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/database_blpua_2025_09_29.dmp > /pgBackup/pgsql15/backup/test/log/restore_blpua_test_$(date +%Y_%m_%d).log 2>&1 & [1] 5300 [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ cat /pgBackup/pgsql15/backup/test/log/restore_blpua_test_2025_09_30.log nohup: ignoring input pg_restore: connecting to database for restore pg_restore: creating SCHEMA "blp" pg_restore: creating TYPE "blp.address" pg_restore: creating TYPE "blp.employment_status" pg_restore: creating DOMAIN "blp.positive_integer" pg_restore: creating FUNCTION "blp.get_salary(integer)" pg_restore: creating FUNCTION "blp.log_update()" pg_restore: creating PROCEDURE "blp.raise_salary(integer, numeric)" pg_restore: creating SEQUENCE "blp.emp_id_seq" pg_restore: creating TABLE "blp.employees" pg_restore: creating MATERIALIZED VIEW "blp.emp_summary" pg_restore: creating SEQUENCE "blp.employees_id_seq" pg_restore: creating SEQUENCE OWNED BY "blp.employees_id_seq" pg_restore: creating VIEW "blp.high_paid_employees" pg_restore: creating TABLE "blp.metrics" pg_restore: creating TABLE "blp.metrics_high" pg_restore: creating SEQUENCE "blp.metrics_id_seq" pg_restore: creating TABLE "blp.metrics_low" pg_restore: creating TABLE "blp.metrics_mid" pg_restore: creating TABLE "blp.metrics_rest" pg_restore: creating TABLE "blp.sales" pg_restore: creating TABLE "blp.sales_2021" pg_restore: creating TABLE "blp.sales_2022" pg_restore: creating TABLE "blp.sales_2023" pg_restore: creating TABLE "blp.sales_2024" pg_restore: creating SEQUENCE "blp.sales_id_seq" pg_restore: creating TABLE "blp.test_data" pg_restore: creating SEQUENCE "blp.test_data_id_seq" pg_restore: creating SEQUENCE OWNED BY "blp.test_data_id_seq" pg_restore: creating TABLE ATTACH "blp.metrics_high" pg_restore: creating TABLE ATTACH "blp.metrics_low" pg_restore: creating TABLE ATTACH "blp.metrics_mid" pg_restore: creating TABLE ATTACH "blp.metrics_rest" pg_restore: creating TABLE ATTACH "blp.sales_2021" pg_restore: creating TABLE ATTACH "blp.sales_2022" pg_restore: creating TABLE ATTACH "blp.sales_2023" pg_restore: creating TABLE ATTACH "blp.sales_2024" pg_restore: creating DEFAULT "blp.employees id" pg_restore: creating DEFAULT "blp.test_data id" pg_restore: processing data for table "blp.employees" pg_restore: processing data for table "blp.metrics_high" pg_restore: processing data for table "blp.metrics_low" pg_restore: processing data for table "blp.metrics_mid" pg_restore: processing data for table "blp.metrics_rest" pg_restore: processing data for table "blp.sales_2021" pg_restore: processing data for table "blp.sales_2022" pg_restore: processing data for table "blp.sales_2023" pg_restore: processing data for table "blp.sales_2024" pg_restore: processing data for table "blp.test_data" pg_restore: executing SEQUENCE SET emp_id_seq pg_restore: executing SEQUENCE SET employees_id_seq pg_restore: executing SEQUENCE SET metrics_id_seq pg_restore: executing SEQUENCE SET sales_id_seq pg_restore: executing SEQUENCE SET test_data_id_seq pg_restore: creating CONSTRAINT "blp.employees employees_pkey" pg_restore: creating CONSTRAINT "blp.metrics metrics_pkey" pg_restore: creating CONSTRAINT "blp.metrics_high metrics_high_pkey" pg_restore: creating CONSTRAINT "blp.metrics_low metrics_low_pkey" pg_restore: creating CONSTRAINT "blp.metrics_mid metrics_mid_pkey" pg_restore: creating CONSTRAINT "blp.metrics_rest metrics_rest_pkey" pg_restore: creating CONSTRAINT "blp.sales sales_pkey" pg_restore: creating CONSTRAINT "blp.sales_2021 sales_2021_pkey" pg_restore: creating CONSTRAINT "blp.sales_2022 sales_2022_pkey" pg_restore: creating CONSTRAINT "blp.sales_2023 sales_2023_pkey" pg_restore: creating CONSTRAINT "blp.sales_2024 sales_2024_pkey" pg_restore: creating CONSTRAINT "blp.test_data test_data_pkey" pg_restore: creating INDEX "blp.idx_employee_name" pg_restore: creating INDEX ATTACH "blp.metrics_high_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_low_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_mid_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_rest_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2021_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2022_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2023_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2024_pkey" pg_restore: creating TRIGGER "blp.employees employee_update_trigger" pg_restore: creating MATERIALIZED VIEW DATA "blp.emp_summary" [postgres@lxtrdpgdsgv01 ~]$
++ pg_restore does not support schema remapping like Oracle’s REMAP_SCHEMA.
++ I want to restore schema blp --> trd.
++ Option A: Restore Dump as it is, Then Rename <--- Best for simplicity
++ Option B: Split Dump into Schema + Data, Modify Both <--- This is more complex, but possible if you must use schema remapping.
++ This is schema dump file : /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp
++ Using --no-owner --no-tablespaces in pg_restore — even if not specified, data still gets written to the default database tablespace. These options just help avoid errors in the log.
A. To Restore schema from own schema’s backup
postgres=# CREATE TABLESPACE ORCL_TB LOCATION '/pgTb/pgsql15/orcl'; CREATE TABLESPACE postgres=# CREATE TABLESPACE ORCL_IX LOCATION '/pgIx/pgsql15/orcl'; CREATE TABLESPACE postgres=# postgres=# CREATE DATABASE ORCL TABLESPACE ORCL_TB; CREATE DATABASE postgres=# -- With NO parallelism [postgres@lxtrdpgdsgv01 ~]$ nohup pg_restore -U postgres -d orcl --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp > /pgBackup/pgsql15/backup/test/log/restore_blpua_test_$(date +%Y_%m_%d).log 2>&1 & [1] 7344 [postgres@lxtrdpgdsgv01 ~]$ postgres=# \c orcl You are now connected to database "orcl" as user "postgres". orcl=# ALTER SCHEMA blp RENAME TO trd; ALTER SCHEMA orcl=# \dn List of schemas Name | Owner --------+------------------- public | pg_database_owner trd | postgres (2 rows) orcl=# [postgres@lxtrdpgdsgv01 ~]$ cat /pgBackup/pgsql15/backup/test/log/restore_blpua_test_2025_09_30.log nohup: ignoring input pg_restore: connecting to database for restore pg_restore: creating SCHEMA "blp" pg_restore: creating TYPE "blp.address" pg_restore: creating TYPE "blp.employment_status" pg_restore: creating DOMAIN "blp.positive_integer" pg_restore: creating FUNCTION "blp.get_salary(integer)" pg_restore: creating FUNCTION "blp.log_update()" pg_restore: creating PROCEDURE "blp.raise_salary(integer, numeric)" pg_restore: creating SEQUENCE "blp.emp_id_seq" pg_restore: creating TABLE "blp.employees" pg_restore: creating MATERIALIZED VIEW "blp.emp_summary" pg_restore: creating SEQUENCE "blp.employees_id_seq" pg_restore: creating SEQUENCE OWNED BY "blp.employees_id_seq" pg_restore: creating VIEW "blp.high_paid_employees" pg_restore: creating TABLE "blp.metrics" pg_restore: creating TABLE "blp.metrics_high" pg_restore: creating SEQUENCE "blp.metrics_id_seq" pg_restore: creating TABLE "blp.metrics_low" pg_restore: creating TABLE "blp.metrics_mid" pg_restore: creating TABLE "blp.metrics_rest" pg_restore: creating TABLE "blp.sales" pg_restore: creating TABLE "blp.sales_2021" pg_restore: creating TABLE "blp.sales_2022" pg_restore: creating TABLE "blp.sales_2023" pg_restore: creating TABLE "blp.sales_2024" pg_restore: creating SEQUENCE "blp.sales_id_seq" pg_restore: creating TABLE "blp.test_data" pg_restore: creating SEQUENCE "blp.test_data_id_seq" pg_restore: creating SEQUENCE OWNED BY "blp.test_data_id_seq" pg_restore: creating TABLE ATTACH "blp.metrics_high" pg_restore: creating TABLE ATTACH "blp.metrics_low" pg_restore: creating TABLE ATTACH "blp.metrics_mid" pg_restore: creating TABLE ATTACH "blp.metrics_rest" pg_restore: creating TABLE ATTACH "blp.sales_2021" pg_restore: creating TABLE ATTACH "blp.sales_2022" pg_restore: creating TABLE ATTACH "blp.sales_2023" pg_restore: creating TABLE ATTACH "blp.sales_2024" pg_restore: creating DEFAULT "blp.employees id" pg_restore: creating DEFAULT "blp.test_data id" pg_restore: processing data for table "blp.employees" pg_restore: processing data for table "blp.metrics_high" pg_restore: processing data for table "blp.metrics_low" pg_restore: processing data for table "blp.metrics_mid" pg_restore: processing data for table "blp.metrics_rest" pg_restore: processing data for table "blp.sales_2021" pg_restore: processing data for table "blp.sales_2022" pg_restore: processing data for table "blp.sales_2023" pg_restore: processing data for table "blp.sales_2024" pg_restore: processing data for table "blp.test_data" pg_restore: executing SEQUENCE SET emp_id_seq pg_restore: executing SEQUENCE SET employees_id_seq pg_restore: executing SEQUENCE SET metrics_id_seq pg_restore: executing SEQUENCE SET sales_id_seq pg_restore: executing SEQUENCE SET test_data_id_seq pg_restore: creating CONSTRAINT "blp.employees employees_pkey" pg_restore: creating CONSTRAINT "blp.metrics metrics_pkey" pg_restore: creating CONSTRAINT "blp.metrics_high metrics_high_pkey" pg_restore: creating CONSTRAINT "blp.metrics_low metrics_low_pkey" pg_restore: creating CONSTRAINT "blp.metrics_mid metrics_mid_pkey" pg_restore: creating CONSTRAINT "blp.metrics_rest metrics_rest_pkey" pg_restore: creating CONSTRAINT "blp.sales sales_pkey" pg_restore: creating CONSTRAINT "blp.sales_2021 sales_2021_pkey" pg_restore: creating CONSTRAINT "blp.sales_2022 sales_2022_pkey" pg_restore: creating CONSTRAINT "blp.sales_2023 sales_2023_pkey" pg_restore: creating CONSTRAINT "blp.sales_2024 sales_2024_pkey" pg_restore: creating CONSTRAINT "blp.test_data test_data_pkey" pg_restore: creating INDEX "blp.idx_employee_name" pg_restore: creating INDEX ATTACH "blp.metrics_high_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_low_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_mid_pkey" pg_restore: creating INDEX ATTACH "blp.metrics_rest_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2021_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2022_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2023_pkey" pg_restore: creating INDEX ATTACH "blp.sales_2024_pkey" pg_restore: creating TRIGGER "blp.employees employee_update_trigger" pg_restore: creating MATERIALIZED VIEW DATA "blp.emp_summary" [postgres@lxtrdpgdsgv01 ~]$ --- OR --- -- With parallelism 4 nohup pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp > /pgBackup/pgsql15/backup/test/log/restore_blpua_test_$(date +%Y_%m_%d).log1 2>&1 & [postgres@lxtrdpgdsgv01 ~]$ ps -ef | grep pg_restore postgres 7089 5102 0 05:49 pts/0 00:00:00 pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp postgres 7091 7089 2 05:49 pts/0 00:00:00 pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp postgres 7092 7089 3 05:49 pts/0 00:00:00 pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp postgres 7093 7089 2 05:49 pts/0 00:00:00 pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp postgres 7094 7089 2 05:49 pts/0 00:00:00 pg_restore -U postgres -d orcl -j4 --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp postgres 7126 5736 0 05:49 pts/1 00:00:00 grep --color=auto pg_restore [postgres@lxtrdpgdsgv01 ~]$
B. To Restore only a specific schema from Full Database Backup
Step 1: Create schema gebua=# CREATE SCHEMA IF NOT EXISTS blp; Step 2: Restore Objects and Data nohup pg_restore -U postgres -d gebua -n blp --no-owner --no-tablespaces -v /pgBackup/pgsql15/backup/test/database_blpua_2025_09_29.dmp > /pgBackup/pgsql15/backup/test/log/restore_blpua_test_$(date +%Y_%m_%d).log_full 2>&1 &
A. Restore Table from own table’s backup
[postgres@lxtrdpgdsgv01 ~]$ pg_restore -l /pgBackup/pgsql15/backup/test/table_blp_employees_2025_09_30.dmp ; ; Archive created at 2025-09-30 02:22:21 EDT ; dbname: blpua ; TOC Entries: 13 ; Compression: -1 ; Dump Version: 1.14-0 ; Format: CUSTOM ; Integer: 4 bytes ; Offset: 8 bytes ; Dumped from database version: 15.13 ; Dumped by pg_dump version: 15.13 ; ; ; Selected TOC Entries: ; 229; 1259 92805 TABLE blp employees postgres 228; 1259 92804 SEQUENCE blp employees_id_seq postgres 4338; 0 0 SEQUENCE OWNED BY blp employees_id_seq postgres 4181; 2604 92808 DEFAULT blp employees id postgres 4331; 0 92805 TABLE DATA blp employees postgres 4339; 0 0 SEQUENCE SET blp employees_id_seq postgres 4183; 2606 92812 CONSTRAINT blp employees employees_pkey postgres 4184; 1259 92824 INDEX blp idx_employee_name postgres 4185; 2620 92829 TRIGGER blp employees employee_update_trigger postgres [postgres@lxtrdpgdsgv01 ~]$ Step 1: Create schema postgres=# \c edpua You are now connected to database "edpua" as user "postgres". edpua=# CREATE SCHEMA IF NOT EXISTS blp; CREATE SCHEMA edpua=# Step 2: Restore Objects and Data [postgres@lxtrdpgdsgv01 ~]$ pg_restore -U postgres -d edpua --no-tablespaces -v /pgBackup/pgsql15/backup/test/table_blp_employees_2025_09_30.dmp pg_restore: connecting to database for restore pg_restore: creating TABLE "blp.employees" pg_restore: creating SEQUENCE "blp.employees_id_seq" pg_restore: creating SEQUENCE OWNED BY "blp.employees_id_seq" pg_restore: creating DEFAULT "blp.employees id" pg_restore: processing data for table "blp.employees" pg_restore: executing SEQUENCE SET employees_id_seq pg_restore: creating CONSTRAINT "blp.employees employees_pkey" pg_restore: creating INDEX "blp.idx_employee_name" pg_restore: creating TRIGGER "blp.employees employee_update_trigger" pg_restore: while PROCESSING TOC: pg_restore: from TOC entry 4185; 2620 92829 TRIGGER employees employee_update_trigger postgres pg_restore: error: could not execute query: ERROR: function blp.log_update() does not exist Command was: CREATE TRIGGER employee_update_trigger AFTER UPDATE ON blp.employees FOR EACH ROW EXECUTE FUNCTION blp.log_update(); pg_restore: warning: errors ignored on restore: 1 [postgres@lxtrdpgdsgv01 ~]$ ++ PostgreSQL does not have a --ignore-errors flag, The above erros ignorable.
B. Restore Single Table data-only from Schema backup
edpua=# TRUNCATE TABLE blp.employees; TRUNCATE TABLE edpua=# [postgres@lxtrdpgdsgv01 ~]$ pg_restore -U postgres -d edpua --data-only -t employees -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp pg_restore: connecting to database for restore pg_restore: processing data for table "blp.employees" [postgres@lxtrdpgdsgv01 ~]$ edpua=# select count(*) from blp.employees; 5000000 <----- edpua=#
C. Restore Single Table from Schema backup
Step 1: Create schema edpua=# CREATE SCHEMA blp; Step 2: Restore Objects and Data [postgres@lxtrdpgdsgv01 ~]$ pg_restore -U postgres -d edpua --clean -t employees -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp pg_restore: connecting to database for restore pg_restore: dropping TABLE employees pg_restore: creating TABLE "blp.employees" pg_restore: processing data for table "blp.employees" [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ psql psql (15.14) Type "help" for help. postgres=# \c edpua You are now connected to database "edpua" as user "postgres". edpua=# select count(*) from blp.employees; count --------- 5000000 <---- (1 row) edpua=#
D. Restore Single Table from Schema backup (add both -n and -t)
[postgres@lxtrdpgdsgv01 ~]$ pg_restore -U postgres -d edpua --clean -n blp -t employees -v /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp pg_restore: connecting to database for restore pg_restore: dropping TABLE employees pg_restore: creating TABLE "blp.employees" pg_restore: processing data for table "blp.employees" [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ psql psql (15.14) Type "help" for help. postgres=# \c edpua You are now connected to database "edpua" as user "postgres". edpua=# select count(*) from blp.employees; count --------- 5000000 <----- (1 row) edpua=#
E. Restoring Using a Plain SQL File (COPY-based)
Step 1: Extracted table data from custom-format dump [postgres@lxtrdpgdsgv01 ~]$ pg_restore -U postgres -n blp -t employees -f /pgBackup/pgsql15/backup/test/blp_employees.sql /pgBackup/pgsql15/backup/test/schema_blp_blpua_2025_09_30.dmp [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ ls -lrth /pgBackup/pgsql15/backup/test/blp_employees.sql -rw-r--r--. 1 postgres postgres 210M Sep 30 09:17 /pgBackup/pgsql15/backup/test/blp_employees.sql [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ head -50 /pgBackup/pgsql15/backup/test/blp_employees.sql -- -- PostgreSQL database dump -- \restrict TthhVsS8JvVxrplYNApzHUalZpygXUqFg2pIvbSH8GTkbJ6WBNyW0JLnuuvkPdt -- Dumped from database version 15.13 -- Dumped by pg_dump version 15.13 SET statement_timeout = 0; SET lock_timeout = 0; SET idle_in_transaction_session_timeout = 0; SET client_encoding = 'UTF8'; SET standard_conforming_strings = on; SELECT pg_catalog.set_config('search_path', '', false); SET check_function_bodies = false; SET xmloption = content; SET client_min_messages = warning; SET row_security = off; SET default_tablespace = ''; SET default_table_access_method = heap; -- -- Name: employees; Type: TABLE; Schema: blp; Owner: postgres -- CREATE TABLE blp.employees ( id integer NOT NULL, name text, salary numeric(10,2), hired_on date ); ALTER TABLE blp.employees OWNER TO postgres; -- -- Data for Name: employees; Type: TABLE DATA; Schema: blp; Owner: postgres -- COPY blp.employees (id, name, salary, hired_on) FROM stdin; 1 Employee_1 70969.47 2005-06-13 2 Employee_2 94341.15 2006-12-09 3 Employee_3 101657.57 2012-07-05 4 Employee_4 54701.92 2010-01-05 5 Employee_5 104229.43 2001-06-28 6 Employee_6 95842.57 2010-10-06 7 Employee_7 50618.08 2015-06-02 [postgres@lxtrdpgdsgv01 ~]$ Step 2: Restore using psql command postgres=# \c edpua You are now connected to database "edpua" as user "postgres". edpua=# edpua=# drop table blp.employees; DROP TABLE edpua=# exit [postgres@lxtrdpgdsgv01 ~]$ psql -U postgres -d edpua < /pgBackup/pgsql15/backup/test/blp_employees.sql [postgres@lxtrdpgdsgv01 ~]$ psql -U postgres -d edpua < /pgBackup/pgsql15/backup/test/blp_employees.sql SET SET SET SET SET set_config ------------ (1 row) SET SET SET SET SET SET CREATE TABLE ALTER TABLE COPY 5000000 [postgres@lxtrdpgdsgv01 ~]$ [postgres@lxtrdpgdsgv01 ~]$ psql psql (15.14) Type "help" for help. postgres=# \c edpua You are now connected to database "edpua" as user "postgres". edpua=# SELECT COUNT(*) FROM blp.employees; count --------- 5000000 <----- (1 row) edpua=#
Caution: Your use of any information or materials on this website is entirely at your own risk. It is provided for educational purposes only. It has been tested internally, however, we do not guarantee that it will work for you. Ensure that you run it in your test environment before using.
Thank you,
Rajasekhar Amudala
Email: br8dba@gmail.com
Linkedin: https://www.linkedin.com/in/rajasekhar-amudala/