mirror of https://github.com/citusdata/citus.git
Add PG18 support for VACUUM/ANALYZE with ONLY option on partitioned distributed tables
parent
990312bf61
commit
02af7f84fc
|
|
@ -1815,21 +1815,26 @@ SELECT create_distributed_table('vac_analyze_only', 'a');
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
INSERT INTO vac_analyze_only VALUES (1), (2), (3);
|
INSERT INTO vac_analyze_only VALUES (1), (2), (3);
|
||||||
|
-- ANALYZE (no ONLY) should recurse into shard placements
|
||||||
ANALYZE vac_analyze_only;
|
ANALYZE vac_analyze_only;
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_analyze) AS analyze_before_only
|
SELECT coalesce(max(last_analyze), 'epoch'::timestamptz) AS analyze_before_only
|
||||||
FROM pg_stat_all_tables
|
FROM pg_stat_user_tables
|
||||||
WHERE relname LIKE 'vac_analyze_only_%'
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%'
|
||||||
\gset
|
\gset
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
-- ANALYZE ONLY should not recurse into shard placements
|
||||||
ANALYZE ONLY vac_analyze_only;
|
ANALYZE ONLY vac_analyze_only;
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_analyze) = :'analyze_before_only' AS analyze_only_skipped
|
SELECT max(last_analyze) = :'analyze_before_only'::timestamptz
|
||||||
FROM pg_stat_all_tables
|
AS analyze_only_skipped
|
||||||
WHERE relname LIKE 'vac_analyze_only_%';
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%';
|
||||||
analyze_only_skipped
|
analyze_only_skipped
|
||||||
---------------------------------------------------------------------
|
---------------------------------------------------------------------
|
||||||
t
|
t
|
||||||
|
|
@ -1837,21 +1842,26 @@ WHERE relname LIKE 'vac_analyze_only_%';
|
||||||
|
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
-- VACUUM (no ONLY) should recurse into shard placements
|
||||||
VACUUM vac_analyze_only;
|
VACUUM vac_analyze_only;
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_vacuum) AS vacuum_before_only
|
SELECT coalesce(max(last_vacuum), 'epoch'::timestamptz) AS vacuum_before_only
|
||||||
FROM pg_stat_all_tables
|
FROM pg_stat_user_tables
|
||||||
WHERE relname LIKE 'vac_analyze_only_%'
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%'
|
||||||
\gset
|
\gset
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
-- VACUUM ONLY should not recurse into shard placements
|
||||||
VACUUM ONLY vac_analyze_only;
|
VACUUM ONLY vac_analyze_only;
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_vacuum) = :'vacuum_before_only' AS vacuum_only_skipped
|
SELECT max(last_vacuum) = :'vacuum_before_only'::timestamptz
|
||||||
FROM pg_stat_all_tables
|
AS vacuum_only_skipped
|
||||||
WHERE relname LIKE 'vac_analyze_only_%';
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%';
|
||||||
vacuum_only_skipped
|
vacuum_only_skipped
|
||||||
---------------------------------------------------------------------
|
---------------------------------------------------------------------
|
||||||
t
|
t
|
||||||
|
|
@ -1862,7 +1872,86 @@ SET search_path TO pg18_vacuum_part;
|
||||||
DROP SCHEMA pg18_vacuum_part CASCADE;
|
DROP SCHEMA pg18_vacuum_part CASCADE;
|
||||||
NOTICE: drop cascades to table vac_analyze_only
|
NOTICE: drop cascades to table vac_analyze_only
|
||||||
SET search_path TO pg18_nn;
|
SET search_path TO pg18_nn;
|
||||||
-- END PG18 Feature: VACUUM/ANALYZE recurse into inheritance children by default
|
-- END PG18 Feature: VACUUM/ANALYZE support ONLY to limit processing to the parent
|
||||||
|
-- PG18 Feature: VACUUM/ANALYZE ONLY on a partitioned distributed table
|
||||||
|
-- Ensure Citus does not recurse into shard placements when ONLY is used
|
||||||
|
-- on the partitioned parent.
|
||||||
|
-- PG18 commit: https://github.com/postgres/postgres/commit/62ddf7ee9
|
||||||
|
CREATE SCHEMA pg18_vacuum_part_dist;
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
SET citus.shard_count = 2;
|
||||||
|
SET citus.shard_replication_factor = 1;
|
||||||
|
CREATE TABLE part_dist (id int, v int) PARTITION BY RANGE (id);
|
||||||
|
CREATE TABLE part_dist_1 PARTITION OF part_dist FOR VALUES FROM (1) TO (100);
|
||||||
|
CREATE TABLE part_dist_2 PARTITION OF part_dist FOR VALUES FROM (100) TO (200);
|
||||||
|
SELECT create_distributed_table('part_dist', 'id');
|
||||||
|
create_distributed_table
|
||||||
|
---------------------------------------------------------------------
|
||||||
|
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
INSERT INTO part_dist
|
||||||
|
SELECT g, g FROM generate_series(1, 199) g;
|
||||||
|
-- ANALYZE (no ONLY) should recurse into partitions and shard placements
|
||||||
|
ANALYZE part_dist;
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
SELECT coalesce(max(last_analyze), 'epoch'::timestamptz) AS analyze_before_only
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%'
|
||||||
|
\gset
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
-- ANALYZE ONLY should not recurse into shard placements
|
||||||
|
ANALYZE ONLY part_dist;
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
SELECT max(last_analyze) = :'analyze_before_only'::timestamptz
|
||||||
|
AS analyze_only_partitioned_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%';
|
||||||
|
analyze_only_partitioned_skipped
|
||||||
|
---------------------------------------------------------------------
|
||||||
|
t
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
-- VACUUM (no ONLY) should recurse into partitions and shard placements
|
||||||
|
VACUUM part_dist;
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
SELECT coalesce(max(last_vacuum), 'epoch'::timestamptz) AS vacuum_before_only
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%'
|
||||||
|
\gset
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
-- VACUUM ONLY parent: core warns and does no work; Citus must not
|
||||||
|
-- propagate to shard placements.
|
||||||
|
VACUUM ONLY part_dist;
|
||||||
|
WARNING: VACUUM ONLY of partitioned table "part_dist" has no effect
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
SELECT max(last_vacuum) = :'vacuum_before_only'::timestamptz
|
||||||
|
AS vacuum_only_partitioned_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%';
|
||||||
|
vacuum_only_partitioned_skipped
|
||||||
|
---------------------------------------------------------------------
|
||||||
|
t
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
DROP SCHEMA pg18_vacuum_part_dist CASCADE;
|
||||||
|
NOTICE: drop cascades to table part_dist
|
||||||
|
SET search_path TO pg18_nn;
|
||||||
|
-- END PG18 Feature: VACUUM/ANALYZE ONLY on partitioned distributed table
|
||||||
-- cleanup with minimum verbosity
|
-- cleanup with minimum verbosity
|
||||||
SET client_min_messages TO ERROR;
|
SET client_min_messages TO ERROR;
|
||||||
RESET search_path;
|
RESET search_path;
|
||||||
|
|
|
||||||
|
|
@ -1125,55 +1125,160 @@ ROLLBACK;
|
||||||
-- PG18 commit: https://github.com/postgres/postgres/commit/62ddf7ee9
|
-- PG18 commit: https://github.com/postgres/postgres/commit/62ddf7ee9
|
||||||
CREATE SCHEMA pg18_vacuum_part;
|
CREATE SCHEMA pg18_vacuum_part;
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
|
||||||
CREATE TABLE vac_analyze_only (a int);
|
CREATE TABLE vac_analyze_only (a int);
|
||||||
SELECT create_distributed_table('vac_analyze_only', 'a');
|
SELECT create_distributed_table('vac_analyze_only', 'a');
|
||||||
INSERT INTO vac_analyze_only VALUES (1), (2), (3);
|
INSERT INTO vac_analyze_only VALUES (1), (2), (3);
|
||||||
|
|
||||||
|
-- ANALYZE (no ONLY) should recurse into shard placements
|
||||||
ANALYZE vac_analyze_only;
|
ANALYZE vac_analyze_only;
|
||||||
|
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_analyze) AS analyze_before_only
|
|
||||||
FROM pg_stat_all_tables
|
SELECT coalesce(max(last_analyze), 'epoch'::timestamptz) AS analyze_before_only
|
||||||
WHERE relname LIKE 'vac_analyze_only_%'
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%'
|
||||||
\gset
|
\gset
|
||||||
|
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
|
||||||
|
-- ANALYZE ONLY should not recurse into shard placements
|
||||||
ANALYZE ONLY vac_analyze_only;
|
ANALYZE ONLY vac_analyze_only;
|
||||||
|
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_analyze) = :'analyze_before_only' AS analyze_only_skipped
|
|
||||||
FROM pg_stat_all_tables
|
SELECT max(last_analyze) = :'analyze_before_only'::timestamptz
|
||||||
WHERE relname LIKE 'vac_analyze_only_%';
|
AS analyze_only_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%';
|
||||||
|
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
|
||||||
|
-- VACUUM (no ONLY) should recurse into shard placements
|
||||||
VACUUM vac_analyze_only;
|
VACUUM vac_analyze_only;
|
||||||
|
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_vacuum) AS vacuum_before_only
|
|
||||||
FROM pg_stat_all_tables
|
SELECT coalesce(max(last_vacuum), 'epoch'::timestamptz) AS vacuum_before_only
|
||||||
WHERE relname LIKE 'vac_analyze_only_%'
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%'
|
||||||
\gset
|
\gset
|
||||||
|
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
|
||||||
|
-- VACUUM ONLY should not recurse into shard placements
|
||||||
VACUUM ONLY vac_analyze_only;
|
VACUUM ONLY vac_analyze_only;
|
||||||
|
|
||||||
\c - - - :worker_1_port
|
\c - - - :worker_1_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
SELECT max(last_vacuum) = :'vacuum_before_only' AS vacuum_only_skipped
|
|
||||||
FROM pg_stat_all_tables
|
SELECT max(last_vacuum) = :'vacuum_before_only'::timestamptz
|
||||||
WHERE relname LIKE 'vac_analyze_only_%';
|
AS vacuum_only_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part'
|
||||||
|
AND relname LIKE 'vac_analyze_only_%';
|
||||||
|
|
||||||
\c - - - :master_port
|
\c - - - :master_port
|
||||||
SET search_path TO pg18_vacuum_part;
|
SET search_path TO pg18_vacuum_part;
|
||||||
|
|
||||||
DROP SCHEMA pg18_vacuum_part CASCADE;
|
DROP SCHEMA pg18_vacuum_part CASCADE;
|
||||||
SET search_path TO pg18_nn;
|
SET search_path TO pg18_nn;
|
||||||
-- END PG18 Feature: VACUUM/ANALYZE recurse into inheritance children by default
|
|
||||||
|
-- END PG18 Feature: VACUUM/ANALYZE support ONLY to limit processing to the parent
|
||||||
|
|
||||||
|
-- PG18 Feature: VACUUM/ANALYZE ONLY on a partitioned distributed table
|
||||||
|
-- Ensure Citus does not recurse into shard placements when ONLY is used
|
||||||
|
-- on the partitioned parent.
|
||||||
|
-- PG18 commit: https://github.com/postgres/postgres/commit/62ddf7ee9
|
||||||
|
CREATE SCHEMA pg18_vacuum_part_dist;
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
SET citus.shard_count = 2;
|
||||||
|
SET citus.shard_replication_factor = 1;
|
||||||
|
|
||||||
|
CREATE TABLE part_dist (id int, v int) PARTITION BY RANGE (id);
|
||||||
|
CREATE TABLE part_dist_1 PARTITION OF part_dist FOR VALUES FROM (1) TO (100);
|
||||||
|
CREATE TABLE part_dist_2 PARTITION OF part_dist FOR VALUES FROM (100) TO (200);
|
||||||
|
|
||||||
|
SELECT create_distributed_table('part_dist', 'id');
|
||||||
|
|
||||||
|
INSERT INTO part_dist
|
||||||
|
SELECT g, g FROM generate_series(1, 199) g;
|
||||||
|
|
||||||
|
-- ANALYZE (no ONLY) should recurse into partitions and shard placements
|
||||||
|
ANALYZE part_dist;
|
||||||
|
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
SELECT coalesce(max(last_analyze), 'epoch'::timestamptz) AS analyze_before_only
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%'
|
||||||
|
\gset
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
-- ANALYZE ONLY should not recurse into shard placements
|
||||||
|
ANALYZE ONLY part_dist;
|
||||||
|
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
SELECT max(last_analyze) = :'analyze_before_only'::timestamptz
|
||||||
|
AS analyze_only_partitioned_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%';
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
-- VACUUM (no ONLY) should recurse into partitions and shard placements
|
||||||
|
VACUUM part_dist;
|
||||||
|
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
SELECT coalesce(max(last_vacuum), 'epoch'::timestamptz) AS vacuum_before_only
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%'
|
||||||
|
\gset
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
-- VACUUM ONLY parent: core warns and does no work; Citus must not
|
||||||
|
-- propagate to shard placements.
|
||||||
|
VACUUM ONLY part_dist;
|
||||||
|
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
SELECT max(last_vacuum) = :'vacuum_before_only'::timestamptz
|
||||||
|
AS vacuum_only_partitioned_skipped
|
||||||
|
FROM pg_stat_user_tables
|
||||||
|
WHERE schemaname = 'pg18_vacuum_part_dist'
|
||||||
|
AND relname LIKE 'part_dist_%';
|
||||||
|
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO pg18_vacuum_part_dist;
|
||||||
|
|
||||||
|
DROP SCHEMA pg18_vacuum_part_dist CASCADE;
|
||||||
|
SET search_path TO pg18_nn;
|
||||||
|
|
||||||
|
-- END PG18 Feature: VACUUM/ANALYZE ONLY on partitioned distributed table
|
||||||
|
|
||||||
-- cleanup with minimum verbosity
|
-- cleanup with minimum verbosity
|
||||||
SET client_min_messages TO ERROR;
|
SET client_min_messages TO ERROR;
|
||||||
|
|
|
||||||
Loading…
Reference in New Issue