mirror of
https://github.com/postgres/postgres.git
synced 2026-02-13 07:43:11 -05:00
This commit adds new parameter to VACUUM command, TRUNCATE, which specifies that VACUUM should attempt to truncate off any empty pages at the end of the table and allow the disk space for the truncated pages to be returned to the operating system. This parameter, if specified, overrides the vacuum_truncate reloption. If neither the reloption nor the VACUUM option is used, the default is true, as before. Author: Fujii Masao Reviewed-by: Julien Rouhaud, Masahiko Sawada Discussion: https://postgr.es/m/CAD21AoD+qtrSDL=GSma4Wd3kLYLeRC0hPna-YAdkDeV4z156vg@mail.gmail.com
207 lines
6.5 KiB
SQL
207 lines
6.5 KiB
SQL
--
|
|
-- VACUUM
|
|
--
|
|
|
|
CREATE TABLE vactst (i INT);
|
|
INSERT INTO vactst VALUES (1);
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst VALUES (0);
|
|
SELECT count(*) FROM vactst;
|
|
DELETE FROM vactst WHERE i != 0;
|
|
SELECT * FROM vactst;
|
|
VACUUM FULL vactst;
|
|
UPDATE vactst SET i = i + 1;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst SELECT * FROM vactst;
|
|
INSERT INTO vactst VALUES (0);
|
|
SELECT count(*) FROM vactst;
|
|
DELETE FROM vactst WHERE i != 0;
|
|
VACUUM (FULL) vactst;
|
|
DELETE FROM vactst;
|
|
SELECT * FROM vactst;
|
|
|
|
VACUUM (FULL, FREEZE) vactst;
|
|
VACUUM (ANALYZE, FULL) vactst;
|
|
|
|
CREATE TABLE vaccluster (i INT PRIMARY KEY);
|
|
ALTER TABLE vaccluster CLUSTER ON vaccluster_pkey;
|
|
CLUSTER vaccluster;
|
|
|
|
CREATE FUNCTION do_analyze() RETURNS VOID VOLATILE LANGUAGE SQL
|
|
AS 'ANALYZE pg_am';
|
|
CREATE FUNCTION wrap_do_analyze(c INT) RETURNS INT IMMUTABLE LANGUAGE SQL
|
|
AS 'SELECT $1 FROM do_analyze()';
|
|
CREATE INDEX ON vaccluster(wrap_do_analyze(i));
|
|
INSERT INTO vaccluster VALUES (1), (2);
|
|
ANALYZE vaccluster;
|
|
|
|
VACUUM FULL pg_am;
|
|
VACUUM FULL pg_class;
|
|
VACUUM FULL pg_database;
|
|
VACUUM FULL vaccluster;
|
|
VACUUM FULL vactst;
|
|
|
|
VACUUM (DISABLE_PAGE_SKIPPING) vaccluster;
|
|
|
|
-- INDEX_CLEANUP option
|
|
CREATE TABLE no_index_cleanup (i INT PRIMARY KEY) WITH (vacuum_index_cleanup = false);
|
|
VACUUM (INDEX_CLEANUP FALSE) vaccluster;
|
|
VACUUM (INDEX_CLEANUP FALSE) vactst; -- index cleanup option is ignored if no indexes
|
|
VACUUM (INDEX_CLEANUP FALSE, FREEZE TRUE) vaccluster;
|
|
-- index cleanup option is ignored if VACUUM FULL
|
|
VACUUM (INDEX_CLEANUP TRUE, FULL TRUE) no_index_cleanup;
|
|
VACUUM (FULL TRUE) no_index_cleanup;
|
|
|
|
-- TRUNCATE option
|
|
CREATE TABLE vac_truncate_test(i INT NOT NULL, j text)
|
|
WITH (vacuum_truncate=true, autovacuum_enabled=false);
|
|
INSERT INTO vac_truncate_test VALUES (1, NULL), (NULL, NULL);
|
|
VACUUM (TRUNCATE FALSE) vac_truncate_test;
|
|
SELECT pg_relation_size('vac_truncate_test') > 0;
|
|
VACUUM vac_truncate_test;
|
|
SELECT pg_relation_size('vac_truncate_test') = 0;
|
|
VACUUM (TRUNCATE FALSE, FULL TRUE) vac_truncate_test;
|
|
DROP TABLE vac_truncate_test;
|
|
|
|
-- partitioned table
|
|
CREATE TABLE vacparted (a int, b char) PARTITION BY LIST (a);
|
|
CREATE TABLE vacparted1 PARTITION OF vacparted FOR VALUES IN (1);
|
|
INSERT INTO vacparted VALUES (1, 'a');
|
|
UPDATE vacparted SET b = 'b';
|
|
VACUUM (ANALYZE) vacparted;
|
|
VACUUM (FULL) vacparted;
|
|
VACUUM (FREEZE) vacparted;
|
|
|
|
-- check behavior with duplicate column mentions
|
|
VACUUM ANALYZE vacparted(a,b,a);
|
|
ANALYZE vacparted(a,b,b);
|
|
|
|
-- multiple tables specified
|
|
VACUUM vaccluster, vactst;
|
|
VACUUM vacparted, does_not_exist;
|
|
VACUUM (FREEZE) vacparted, vaccluster, vactst;
|
|
VACUUM (FREEZE) does_not_exist, vaccluster;
|
|
VACUUM ANALYZE vactst, vacparted (a);
|
|
VACUUM ANALYZE vactst (does_not_exist), vacparted (b);
|
|
VACUUM FULL vacparted, vactst;
|
|
VACUUM FULL vactst, vacparted (a, b), vaccluster (i);
|
|
ANALYZE vactst, vacparted;
|
|
ANALYZE vacparted (b), vactst;
|
|
ANALYZE vactst, does_not_exist, vacparted;
|
|
ANALYZE vactst (i), vacparted (does_not_exist);
|
|
|
|
-- parenthesized syntax for ANALYZE
|
|
ANALYZE (VERBOSE) does_not_exist;
|
|
ANALYZE (nonexistent-arg) does_not_exist;
|
|
ANALYZE (nonexistentarg) does_not_exit;
|
|
|
|
-- ensure argument order independence, and that SKIP_LOCKED on non-existing
|
|
-- relation still errors out.
|
|
ANALYZE (SKIP_LOCKED, VERBOSE) does_not_exist;
|
|
ANALYZE (VERBOSE, SKIP_LOCKED) does_not_exist;
|
|
|
|
-- SKIP_LOCKED option
|
|
VACUUM (SKIP_LOCKED) vactst;
|
|
VACUUM (SKIP_LOCKED, FULL) vactst;
|
|
ANALYZE (SKIP_LOCKED) vactst;
|
|
|
|
DROP TABLE vaccluster;
|
|
DROP TABLE vactst;
|
|
DROP TABLE vacparted;
|
|
DROP TABLE no_index_cleanup;
|
|
|
|
-- relation ownership, WARNING logs generated as all are skipped.
|
|
CREATE TABLE vacowned (a int);
|
|
CREATE TABLE vacowned_parted (a int) PARTITION BY LIST (a);
|
|
CREATE TABLE vacowned_part1 PARTITION OF vacowned_parted FOR VALUES IN (1);
|
|
CREATE TABLE vacowned_part2 PARTITION OF vacowned_parted FOR VALUES IN (2);
|
|
CREATE ROLE regress_vacuum;
|
|
SET ROLE regress_vacuum;
|
|
-- Simple table
|
|
VACUUM vacowned;
|
|
ANALYZE vacowned;
|
|
VACUUM (ANALYZE) vacowned;
|
|
-- Catalog
|
|
VACUUM pg_catalog.pg_class;
|
|
ANALYZE pg_catalog.pg_class;
|
|
VACUUM (ANALYZE) pg_catalog.pg_class;
|
|
-- Shared catalog
|
|
VACUUM pg_catalog.pg_authid;
|
|
ANALYZE pg_catalog.pg_authid;
|
|
VACUUM (ANALYZE) pg_catalog.pg_authid;
|
|
-- Partitioned table and its partitions, nothing owned by other user.
|
|
-- Relations are not listed in a single command to test ownership
|
|
-- independently.
|
|
VACUUM vacowned_parted;
|
|
VACUUM vacowned_part1;
|
|
VACUUM vacowned_part2;
|
|
ANALYZE vacowned_parted;
|
|
ANALYZE vacowned_part1;
|
|
ANALYZE vacowned_part2;
|
|
VACUUM (ANALYZE) vacowned_parted;
|
|
VACUUM (ANALYZE) vacowned_part1;
|
|
VACUUM (ANALYZE) vacowned_part2;
|
|
RESET ROLE;
|
|
-- Partitioned table and one partition owned by other user.
|
|
ALTER TABLE vacowned_parted OWNER TO regress_vacuum;
|
|
ALTER TABLE vacowned_part1 OWNER TO regress_vacuum;
|
|
SET ROLE regress_vacuum;
|
|
VACUUM vacowned_parted;
|
|
VACUUM vacowned_part1;
|
|
VACUUM vacowned_part2;
|
|
ANALYZE vacowned_parted;
|
|
ANALYZE vacowned_part1;
|
|
ANALYZE vacowned_part2;
|
|
VACUUM (ANALYZE) vacowned_parted;
|
|
VACUUM (ANALYZE) vacowned_part1;
|
|
VACUUM (ANALYZE) vacowned_part2;
|
|
RESET ROLE;
|
|
-- Only one partition owned by other user.
|
|
ALTER TABLE vacowned_parted OWNER TO CURRENT_USER;
|
|
SET ROLE regress_vacuum;
|
|
VACUUM vacowned_parted;
|
|
VACUUM vacowned_part1;
|
|
VACUUM vacowned_part2;
|
|
ANALYZE vacowned_parted;
|
|
ANALYZE vacowned_part1;
|
|
ANALYZE vacowned_part2;
|
|
VACUUM (ANALYZE) vacowned_parted;
|
|
VACUUM (ANALYZE) vacowned_part1;
|
|
VACUUM (ANALYZE) vacowned_part2;
|
|
RESET ROLE;
|
|
-- Only partitioned table owned by other user.
|
|
ALTER TABLE vacowned_parted OWNER TO regress_vacuum;
|
|
ALTER TABLE vacowned_part1 OWNER TO CURRENT_USER;
|
|
SET ROLE regress_vacuum;
|
|
VACUUM vacowned_parted;
|
|
VACUUM vacowned_part1;
|
|
VACUUM vacowned_part2;
|
|
ANALYZE vacowned_parted;
|
|
ANALYZE vacowned_part1;
|
|
ANALYZE vacowned_part2;
|
|
VACUUM (ANALYZE) vacowned_parted;
|
|
VACUUM (ANALYZE) vacowned_part1;
|
|
VACUUM (ANALYZE) vacowned_part2;
|
|
RESET ROLE;
|
|
DROP TABLE vacowned;
|
|
DROP TABLE vacowned_parted;
|
|
DROP ROLE regress_vacuum;
|