Name
pg_reorg -- Reorganize tables in PostgreSQL databases without any locks.
Synopsis
pg_reorg [OPTIONS]
The following options can be specified in OPTIONS.
See also "Options" for details.
- Reorg Options
- -o [--order-by] columns [,...]
- -n [--no-order]
- -t [--table] table
- -T [--wait-timeout] seconds
- -Z [--no-analyze]
- Connection Options
- -a, --all : reorganize all databases
- -d, --dbname=DBNAME : database to connect
- -h, --host=HOSTNAME : database server host or socket directory
- -p, --port=PORT : database server port
- -U, --username=USERNAME : user name to connect as
- -W, --password : force password prompt
- Generic Options
- -e, --echo : echo queries
- -E, --elevel=LEVEL : set output message level
- --help : show the help, then exit
- --version : output version information, then exit
Description
pg_reorg is an utility program to reorganize tables in PostgreSQL databases.
Unlike clusterdb, it doesn't block any selections and updates during reorganization.
You can choose one of the following methods to reorganize.
- Online CLUSTER (ordered by cluster index)
- Ordered by specified columns
- Online VACUUM FULL (packing rows only)
NOTICE:
- Only superusers can use the utility.
- Target table must have PRIMARY KEY.
Examples
Execute the following command to do online CLUSTER to all tables in test database.
$ pg_reorg test
Execute the following command to do online VACUUM FULL to foo table in test database.
$ pg_reorg --no-order --table foo -d test
Options
pg_reorg has the following command line options:
Reorg Options
Options to order rows.
If not specified, pg_reorg do online CLUSTER using cluster indexes.
Only one option can be specified.
Options to specify target tables or databases.
- -n
--no-order
- Do online VACUUM FULL.
- -o columns [,...]
--order-by=columns [,...]
- Do online CLUSTER ordered by specified columns.
-
-t table
--table=table
- Reorganize table only. If you don't specify this option, all tables in specified databases are reorganized.
- -Z
--no-analyze
- Do ANALYZE after reorganization. If you don't specify this option, ANALYZE is performed automatically after reorg.
-
-T seconds
--wait-timeout=seconds
-
pg_reorg needs to take an exclusive lock at the end of the reorganization.
This setting controls how long it wait for acquiring the lock in seconds.
If the lock cannot be taken even after the duration, pg_reorg forces to cancel conflicted queries.
Also, if the server version is 8.4 or newer, pg_reorg forces to disconnect conflicted backends after twice time passed.
The default is 60 seconds.
- -Z
--no-analyze
- Disable ANALYZE after the reorganization.
If not specified, run ANALYZE after the reorganization.
Connection Options
Options to connect to servers.
You cannot use --all and --dbname or --table together.
- -a
--all
- Reorganize all databases.
-
-d dbname
--dbname dbname
- Specifies the name of the database to be reorganized. If this is not specified and -a (or --all) is not used, the database name is read from the environment variable PGDATABASE. If that is not set, the user name specified for the connection is used.
- -h host
--host host
- Specifies the host name of the machine on which the server is running. If the value begins with a slash, it is used as the directory for the Unix domain socket.
- -p port
--port port
- Specifies the TCP port or local Unix domain socket file extension on which the server is listening for connections.
- -U username
--username username
- User name to connect as.
- -W
--password
- Force pg_reorg to prompt for a password before connecting to a database.
- This option is never essential, since pg_reorg will automatically prompt for a password if the server demands password authentication. However, vacuumdb will waste a connection attempt finding out that the server wants a password. In some cases it is worth typing -W to avoid the extra connection attempt.
Generic Options
- -e
--echo
- Echo commands sent to server.
- -E
--elevel
- Choose the output message level from DEBUG, INFO, NOTICE, WARNING, ERROR, LOG, FATAL, and PANIC.
The default is INFO.
- --help
- Show usage of the program.
- --version
- Show the version number of the program.
Environment
-
PGDATABASE
PGHOST
PGPORT
PGUSER
- Default connection parameters
This utility, like most other PostgreSQL utilities, also uses the environment variables supported by libpq (see Environment Variables).
Diagnostics
Error messages are reported when pg_reorg fails.
The following list shows the cause of errors.
You need to cleanup by hand after fatal erros.
To cleanup, execute $PGHOME/share/contrib/uninstall_pg_reorg.sql to the database where the error occured and then execute $PGHOME/share/contrib/pg_reorg.sql. (Do uninstall and reinstall.)
- pg_reorg : reorg database "template1" ... skipped
- pg_reorg is not installed in the database when --all option is specified.
- Do register pg_reorg to the database.
- ERROR: pg_reorg is not installed
- pg_reorg is not installed in the database specified by --dbname.
- Do register pg_reorg to the database.
- ERROR: relation "table" has no primary key
- The target table doesn't have PRIMARY KEY.
- Define PRIMARY KEY to the table. (ALTER TABLE ADD PRIMARY KEY)
- ERROR: relation "table" has no cluster key
- The target table doesn't have CLUSTER KEY.
- Define CLUSTER KEY to the table. (ALTER TABLE CLUSTER)
- pg_reorg : query failed: ERROR: column "col" does not exist
- The target table doesn't have columns specified by --order-by option.
- Specify existing columns.
- ERROR: permission denied for schema reorg
- Permission error.
- pg_reorg must be executed by superusers.
- pg_reorg : query failed: ERROR: trigger "z_reorg_trigger" for relation "tbl" already exists
- The target table already has a trigger named "z_reorg_trigger".
- Delete or rename the trigger.
- pg_reorg : trigger conflicted for tbl
- The target table already has a trigger which follows by "z_reorg_trigger" in alphabetical order.
- Delete or rename the trigger.
Restrictions
pg_reorg has the following restrictions.
Be careful to avoid data corruptions.
Temp tables
pg_reorg cannot reorganize temp tables.
GiST indexes
pg_reorg cannot reorganize tables using GiST indexes.
DDL commands
You cannot do DDL commands except VACUUM and ANALYZE during pg_reorg.
In many case pg_reorg would fail and rollback collectly, but there are some cases ending with data-corruption .
- TRUNCATE
- TRUNCATE is lost. Deleted rows still exist after pg_reorg.
- CREATE INDEX
- It causes index corruptions.
- ALTER TABLE ... ADD COLUMN
- It causes lost of data. Newly added columns are initialized with NULLs.
- ALTER TABLE ... ALTER COLUMN TYPE
- It causes data corruptions.
- ALTER TABLE ... SET TABLESPACE
- It causes data corruptions by wrong relfilenode.
Details
pg_reorg creates a work table in reorg schema and sorts rows in it.
Then, it updates system catalog directly to swap the work table and the original one.
Installations
pg_reorg can be installed like standard contrib modules.
Build from source
Place pg_reorg to $PGHOME/contrib/ and input make, make install.
Register to database
Start PostgreSQL and execute pg_reorg.sql in $PGHOME/share/contrib.
Requirements
- PostgreSQL version
- PostgreSQL 8.3, 8.4, 9.0
- OS
- RHEL 5.2, Windows XP SP3
- Disks
- Requires amount of disks twice larger than target table and indexes. (If the total size of targets are 1GB, additional 2GB of disks are required.)
See Also
clusterdb,
vacuumdb