citus/src/test/regress/sql/multi_alter_table_statement...

760 lines
31 KiB
PL/PgSQL

--
-- MULTI_ALTER_TABLE_STATEMENTS
--
CREATE SCHEMA multi_alter_table_statements;
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 220000;
-- Check that we can run ALTER TABLE statements on distributed tables.
-- We set the shardid sequence here so that the shardids in this test
-- aren't affected by changes to the previous tests.
CREATE TABLE lineitem_alter (
l_orderkey bigint not null,
l_partkey integer not null,
l_suppkey integer not null,
l_linenumber integer not null,
l_quantity decimal(15, 2) not null,
l_extendedprice decimal(15, 2) not null,
l_discount decimal(15, 2) not null,
l_tax decimal(15, 2) not null,
l_returnflag char(1) not null,
l_linestatus char(1) not null,
l_shipdate date not null,
l_commitdate date not null,
l_receiptdate date not null,
l_shipinstruct char(25) not null,
l_shipmode char(10) not null,
l_comment varchar(44) not null
)
WITH ( fillfactor = 80 );
SELECT create_distributed_table('lineitem_alter', 'l_orderkey', 'append');
SELECT master_create_empty_shard('lineitem_alter') AS shardid \gset
\set lineitem_1_data_file :abs_srcdir '/data/lineitem.1.data'
copy lineitem_alter FROM :'lineitem_1_data_file' with (delimiter '|', append_to_shard :shardid);
-- verify that the storage options made it to the table definitions
SELECT relname, reloptions FROM pg_class WHERE relname = 'lineitem_alter';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'lineitem_alter%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 221000;
-- Verify that we can add columns
ALTER TABLE lineitem_alter ADD COLUMN float_column FLOAT;
ALTER TABLE lineitem_alter ADD COLUMN date_column DATE;
ALTER TABLE lineitem_alter ADD COLUMN int_column1 INTEGER DEFAULT 1;
ALTER TABLE lineitem_alter ADD COLUMN int_column2 INTEGER DEFAULT 2;
ALTER TABLE lineitem_alter ADD COLUMN null_column INTEGER;
-- show changed schema on one worker
\c - - - :worker_1_port
SELECT attname, atttypid::regtype
FROM
(SELECT oid FROM pg_class WHERE relname LIKE 'lineitem_alter_%' ORDER BY relname LIMIT 1) pc
JOIN pg_attribute ON (pc.oid = pg_attribute.attrelid)
ORDER BY attnum;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 222000;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
SELECT float_column, count(*) FROM lineitem_alter GROUP BY float_column;
SELECT int_column1, count(*) FROM lineitem_alter GROUP BY int_column1;
-- Verify that SET|DROP DEFAULT works
ALTER TABLE lineitem_alter ALTER COLUMN float_column SET DEFAULT 1;
ALTER TABLE lineitem_alter ALTER COLUMN int_column1 DROP DEFAULT;
-- COPY to verify that default values take effect
SELECT master_create_empty_shard('lineitem_alter') as shardid \gset
copy lineitem_alter (l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment) FROM :'lineitem_1_data_file' with (delimiter '|', append_to_shard :shardid);
SELECT float_column, count(*) FROM lineitem_alter GROUP BY float_column;
SELECT int_column1, count(*) FROM lineitem_alter GROUP BY int_column1;
-- Verify that SET NOT NULL works
ALTER TABLE lineitem_alter ALTER COLUMN int_column2 SET NOT NULL;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
-- Drop default so that NULLs will be inserted for this column
ALTER TABLE lineitem_alter ALTER COLUMN int_column2 DROP DEFAULT;
-- COPY should fail because it will try to insert NULLs for a NOT NULL column
-- Note, this operation will create a table on the workers but it won't be in the metadata
BEGIN;
SELECT master_create_empty_shard('lineitem_alter') as shardid \gset
copy lineitem_alter (l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment) FROM :'lineitem_1_data_file' with (delimiter '|', append_to_shard :shardid);
END;
-- Verify that DROP NOT NULL works
ALTER TABLE lineitem_alter ALTER COLUMN int_column2 DROP NOT NULL;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
-- COPY should succeed now
SELECT master_create_empty_shard('lineitem_alter') as shardid \gset
copy lineitem_alter (l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment) FROM :'lineitem_1_data_file' with (delimiter '|', append_to_shard :shardid);
SELECT count(*) from lineitem_alter;
-- Verify that SET DATA TYPE works
SELECT int_column2, pg_typeof(int_column2), count(*) from lineitem_alter GROUP BY int_column2;
ALTER TABLE lineitem_alter ALTER COLUMN int_column2 SET DATA TYPE FLOAT;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
SELECT int_column2, pg_typeof(int_column2), count(*) from lineitem_alter GROUP BY int_column2;
-- Verify that DROP COLUMN works
ALTER TABLE lineitem_alter DROP COLUMN int_column1;
ALTER TABLE lineitem_alter DROP COLUMN float_column;
ALTER TABLE lineitem_alter DROP COLUMN date_column;
-- Verify that RENAME COLUMN works
ALTER TABLE lineitem_alter RENAME COLUMN l_orderkey TO l_orderkey_renamed;
SELECT SUM(l_orderkey_renamed) FROM lineitem_alter;
-- Verify that IF EXISTS works as expected
ALTER TABLE non_existent_table ADD COLUMN new_column INTEGER;
ALTER TABLE IF EXISTS non_existent_table ADD COLUMN new_column INTEGER;
ALTER TABLE IF EXISTS lineitem_alter ALTER COLUMN int_column2 SET DATA TYPE INTEGER;
ALTER TABLE lineitem_alter DROP COLUMN non_existent_column;
ALTER TABLE lineitem_alter DROP COLUMN IF EXISTS non_existent_column;
ALTER TABLE lineitem_alter DROP COLUMN IF EXISTS int_column2;
-- Verify with IF EXISTS for extant table
ALTER TABLE IF EXISTS lineitem_alter RENAME COLUMN l_orderkey_renamed TO l_orderkey;
SELECT SUM(l_orderkey) FROM lineitem_alter;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
-- Verify that we can execute commands with multiple subcommands
ALTER TABLE lineitem_alter ADD COLUMN int_column1 INTEGER,
ADD COLUMN int_column2 INTEGER;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
ALTER TABLE lineitem_alter ADD COLUMN int_column3 INTEGER,
ALTER COLUMN int_column1 SET STATISTICS 10;
ALTER TABLE lineitem_alter DROP COLUMN int_column1, DROP COLUMN int_column2;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
-- Verify that we cannot execute alter commands on the distribution column
ALTER TABLE lineitem_alter ALTER COLUMN l_orderkey DROP NOT NULL;
ALTER TABLE lineitem_alter DROP COLUMN l_orderkey;
-- Verify that we error out on unsupported statement types
ALTER TABLE lineitem_alter ALTER COLUMN l_orderkey SET STATISTICS 100;
ALTER TABLE lineitem_alter DROP CONSTRAINT IF EXISTS non_existent_contraint;
ALTER TABLE lineitem_alter SET WITHOUT OIDS;
-- Verify that we error out in case of postgres errors on supported statement
-- types
ALTER TABLE lineitem_alter ADD COLUMN new_column non_existent_type;
ALTER TABLE lineitem_alter ALTER COLUMN null_column SET NOT NULL;
ALTER TABLE lineitem_alter ALTER COLUMN l_partkey SET DEFAULT 'a';
-- Verify that we error out on RENAME CONSTRAINT statement
ALTER TABLE lineitem_alter RENAME CONSTRAINT constraint_a TO constraint_b;
-- Verify that IF EXISTS works as expected with RENAME statements
ALTER TABLE non_existent_table RENAME TO non_existent_table_renamed;
ALTER TABLE IF EXISTS non_existent_table RENAME TO non_existent_table_renamed;
ALTER TABLE IF EXISTS non_existent_table RENAME COLUMN column1 TO column2;
-- Verify that none of the failed alter table commands took effect on the master
-- node
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
-- verify that non-propagated ddl commands are allowed inside a transaction block
SET citus.enable_ddl_propagation to false;
BEGIN;
CREATE INDEX temp_index_1 ON lineitem_alter(l_linenumber);
COMMIT;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
DROP INDEX temp_index_1;
-- verify that single distributed ddl commands are allowed inside a transaction block
SET citus.enable_ddl_propagation to true;
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
COMMIT;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
DROP INDEX temp_index_2;
-- and so are multiple ddl statements
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
ALTER TABLE lineitem_alter ADD COLUMN first integer;
COMMIT;
SELECT "Column", "Type", "Modifiers" FROM table_desc WHERE relid='lineitem_alter'::regclass;
SELECT "Column", "Type", "Definition" FROM index_attrs WHERE
relid = 'temp_index_2'::regclass;
ALTER TABLE lineitem_alter DROP COLUMN first;
DROP INDEX temp_index_2;
-- ensure that user-specified rollback causes full rollback
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
CREATE INDEX temp_index_3 ON lineitem_alter(l_partkey);
ROLLBACK;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
-- ensure that errors cause full rollback
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
ROLLBACK;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
-- verify that SAVEPOINT is allowed...
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
SAVEPOINT my_savepoint;
CREATE INDEX temp_index_3 ON lineitem_alter(l_partkey);
ROLLBACK;
-- and also rolling back to it is also allowed
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
SAVEPOINT my_savepoint;
CREATE INDEX temp_index_3 ON lineitem_alter(l_partkey);
ROLLBACK TO my_savepoint;
COMMIT;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
DROP INDEX temp_index_2;
-- Add column on only one worker...
\c - - - :worker_2_port
ALTER TABLE multi_alter_table_statements.lineitem_alter_220000 ADD COLUMN first integer;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 223000;
-- and try to add it in a multi-statement block, which fails
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
ALTER TABLE lineitem_alter ADD COLUMN first integer;
COMMIT;
-- Nothing from the block should have committed
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
-- Create single-shard table (to avoid deadlocks in the upcoming test hackery)
CREATE TABLE single_shard_items (id integer NOT NULL, name text);
SET citus.shard_count TO 1;
SET citus.shard_replication_factor TO 2;
SELECT create_distributed_table('single_shard_items', 'id', 'hash');
-- Verify that ALTER TABLE .. REPLICATION IDENTITY [USING INDEX]* .. works
CREATE UNIQUE INDEX replica_idx on single_shard_items(id);
SELECT relreplident FROM pg_class WHERE relname = 'single_shard_items';
SELECT run_command_on_workers('SELECT relreplident FROM pg_class WHERE relname LIKE ''single_shard_items_%'' LIMIT 1;');
ALTER TABLE single_shard_items REPLICA IDENTITY nothing;
SELECT relreplident FROM pg_class WHERE relname = 'single_shard_items';
SELECT run_command_on_workers('SELECT relreplident FROM pg_class WHERE relname LIKE ''single_shard_items_%'' LIMIT 1;');
ALTER TABLE single_shard_items REPLICA IDENTITY full;
SELECT relreplident FROM pg_class WHERE relname = 'single_shard_items';
SELECT run_command_on_workers('SELECT relreplident FROM pg_class WHERE relname LIKE ''single_shard_items_%'' LIMIT 1;');
ALTER TABLE single_shard_items REPLICA IDENTITY USING INDEX replica_idx;
SELECT relreplident FROM pg_class WHERE relname = 'single_shard_items';
SELECT run_command_on_workers('SELECT relreplident FROM pg_class WHERE relname LIKE ''single_shard_items_%'' LIMIT 1;');
ALTER TABLE single_shard_items REPLICA IDENTITY default, REPLICA IDENTITY USING INDEX replica_idx, REPLICA IDENTITY nothing;
SELECT relreplident FROM pg_class WHERE relname = 'single_shard_items';
SELECT run_command_on_workers('SELECT relreplident FROM pg_class WHERE relname LIKE ''single_shard_items_%'' LIMIT 1;');
ALTER TABLE single_shard_items ADD COLUMN test_col int, REPLICA IDENTITY full;
DROP INDEX replica_idx;
ALTER TABLE single_shard_items REPLICA IDENTITY default;
-- Drop the column from the worker...
\c - - - :worker_2_port
ALTER TABLE multi_alter_table_statements.lineitem_alter_220000 DROP COLUMN first;
-- Create table to trigger at-xact-end (deferred) failure
CREATE TABLE ddl_commands (command text UNIQUE DEFERRABLE INITIALLY DEFERRED);
-- Use an event trigger to log all DDL event tags in it
SET citus.enable_metadata_sync TO OFF;
CREATE FUNCTION log_ddl_tag() RETURNS event_trigger AS $ldt$
BEGIN
INSERT INTO ddl_commands VALUES (tg_tag);
END;
$ldt$ LANGUAGE plpgsql;
RESET citus.enable_metadata_sync;
CREATE EVENT TRIGGER log_ddl_tag ON ddl_command_end EXECUTE PROCEDURE log_ddl_tag();
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 224000;
-- The above trigger will cause failure at transaction end on one placement.
-- Citus always uses 2PC. 2PC should handle this "best" (no divergence)
BEGIN;
CREATE INDEX single_index_2 ON single_shard_items(id);
CREATE INDEX single_index_3 ON single_shard_items(name);
COMMIT;
-- Nothing from the block should have committed
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'single_shard_items' ORDER BY 1;
\c - - - :worker_2_port
DROP EVENT TRIGGER log_ddl_tag;
DROP FUNCTION log_ddl_tag();
DROP TABLE ddl_commands;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 225000;
-- Distributed SELECTs may appear after ALTER
BEGIN;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
SELECT count(*) FROM lineitem_alter;
ROLLBACK;
-- and before
BEGIN;
SELECT count(*) FROM lineitem_alter;
CREATE INDEX temp_index_2 ON lineitem_alter(l_orderkey);
COMMIT;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
DROP INDEX temp_index_2;
-- verify that distributed ddl commands are allowed without transaction block as well
-- Reminder: Now Citus always uses 2PC
CREATE INDEX temp_index_3 ON lineitem_alter(l_orderkey);
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
DROP INDEX temp_index_3;
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
-- verify that not any of shard placements are marked as failed when a query failure occurs
CREATE TABLE test_ab (a int, b int);
SET citus.shard_count TO 8;
SELECT create_distributed_table('test_ab', 'a', 'hash');
INSERT INTO test_ab VALUES (2, 10);
INSERT INTO test_ab VALUES (2, 11);
CREATE UNIQUE INDEX temp_unique_index_1 ON test_ab(a);
SELECT shardid FROM pg_dist_shard_placement NATURAL JOIN pg_dist_shard
WHERE logicalrelid='test_ab'::regclass AND shardstate=3;
-- Check that the schema on the worker still looks reasonable
\c - - - :worker_1_port
SELECT attname, atttypid::regtype
FROM
(SELECT oid FROM pg_class WHERE relname LIKE 'lineitem_alter_%' ORDER BY relname LIMIT 1) pc
JOIN pg_attribute ON (pc.oid = pg_attribute.attrelid)
ORDER BY attnum;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 226000;
-- verify that we can rename distributed tables
SHOW citus.enable_ddl_propagation;
ALTER TABLE lineitem_alter RENAME TO lineitem_renamed;
-- verify rename is performed
SELECT relname FROM pg_class WHERE relname = 'lineitem_renamed';
-- show rename worked on one worker, too
\c - - - :worker_1_port
SELECT relname FROM pg_class WHERE relname LIKE 'lineitem_renamed%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 227000;
-- revert it to original name
ALTER TABLE lineitem_renamed RENAME TO lineitem_alter;
-- show rename worked on one worker, too
\c - - - :worker_1_port
SELECT relname FROM pg_class WHERE relname LIKE 'lineitem_alter%' AND relname <> 'lineitem_alter_222001' /* failed copy trails */ ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 228000;
-- verify that we can set and reset storage parameters
ALTER TABLE lineitem_alter SET(fillfactor=40);
SELECT relname, reloptions FROM pg_class WHERE relname = 'lineitem_alter';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'lineitem_alter%' AND relname <> 'lineitem_alter_222001' /* failed copy trails */ ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 229000;
ALTER TABLE lineitem_alter RESET(fillfactor);
SELECT relname, reloptions FROM pg_class WHERE relname = 'lineitem_alter';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'lineitem_alter%' AND relname <> 'lineitem_alter_222001' /* failed copy trails */ ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 230000;
-- verify that we can rename indexes on distributed tables
CREATE INDEX temp_index_1 ON lineitem_alter(l_linenumber);
ALTER INDEX temp_index_1 RENAME TO idx_lineitem_linenumber;
-- verify rename is performed
SELECT relname FROM pg_class WHERE relname = 'idx_lineitem_linenumber';
-- show rename worked on one worker, too
\c - - - :worker_1_port
SELECT relname FROM pg_class WHERE relname LIKE 'idx_lineitem_linenumber%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 231000;
-- now get rid of the index
DROP INDEX idx_lineitem_linenumber;
-- verify that we don't intercept DDL commands if propagation is turned off
SET citus.enable_ddl_propagation to false;
-- table rename statement can be performed on the coordinator only now
ALTER TABLE lineitem_alter RENAME TO lineitem_renamed;
-- verify rename is performed
SELECT relname FROM pg_class WHERE relname = 'lineitem_alter' or relname = 'lineitem_renamed';
-- revert it to original name
ALTER TABLE lineitem_renamed RENAME TO lineitem_alter;
-- this column is added to master table and not workers
ALTER TABLE lineitem_alter ADD COLUMN column_only_added_to_master int;
-- verify newly added column is not present in a worker shard
\c - - - :worker_1_port
SELECT column_only_added_to_master FROM multi_alter_table_statements.lineitem_alter_220000 LIMIT 0;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 232000;
-- ddl propagation flag is reset to default, disable it again
SET citus.enable_ddl_propagation to false;
-- following query succeeds since it accesses an previously existing column
SELECT l_orderkey FROM lineitem_alter LIMIT 0;
-- make master and workers have the same schema again
ALTER TABLE lineitem_alter DROP COLUMN column_only_added_to_master;
-- now this should succeed
SELECT * FROM lineitem_alter LIMIT 0;
-- previously unsupported statements are accepted by postgresql now
ALTER TABLE lineitem_alter ALTER COLUMN l_orderkey SET STATISTICS 100;
ALTER TABLE lineitem_alter DROP CONSTRAINT IF EXISTS non_existent_contraint;
ALTER TABLE lineitem_alter SET WITHOUT OIDS;
-- distribution column still cannot be dropped.
ALTER TABLE lineitem_alter DROP COLUMN l_orderkey;
-- Even unique indexes on l_partkey (non-partition column) are allowed.
-- Citus would have prevented that.
CREATE UNIQUE INDEX unique_lineitem_partkey on lineitem_alter(l_partkey);
SELECT indexname, tablename FROM pg_indexes WHERE tablename = 'lineitem_alter';
-- verify index is not created on worker
\c - - - :worker_1_port
SELECT indexname, tablename FROM pg_indexes WHERE tablename like 'lineitem_alter_%';
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 233000;
-- verify alter table and drop sequence in the same transaction does not cause deadlock
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 2;
CREATE TABLE sequence_deadlock_test (a serial, b serial);
SELECT create_distributed_table('sequence_deadlock_test', 'a');
BEGIN;
ALTER TABLE sequence_deadlock_test ADD COLUMN c int;
-- suppress notice message caused by DROP ... CASCADE to prevent pg version difference
SET client_min_messages TO 'WARNING';
DROP SEQUENCE sequence_deadlock_test_b_seq CASCADE;
RESET client_min_messages;
END;
DROP TABLE sequence_deadlock_test;
-- verify enable/disable trigger all works
SET citus.shard_replication_factor TO 1;
SET citus.shard_count TO 1;
CREATE TABLE trigger_table (
id int,
value text
);
SELECT create_distributed_table('trigger_table', 'id');
-- first set a trigger on a shard
\c - - - :worker_1_port
SET citus.enable_metadata_sync TO OFF;
CREATE OR REPLACE FUNCTION update_value() RETURNS trigger AS $up$
BEGIN
NEW.value := 'trigger enabled';
RETURN NEW;
END;
$up$ LANGUAGE plpgsql;
RESET citus.enable_metadata_sync;
CREATE TRIGGER update_value
BEFORE INSERT ON multi_alter_table_statements.trigger_table_233004
FOR EACH ROW EXECUTE PROCEDURE update_value();
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 234000;
INSERT INTO trigger_table VALUES (1, 'trigger disabled');
SELECT value, count(*) FROM trigger_table GROUP BY value ORDER BY value;
ALTER TABLE trigger_table DISABLE TRIGGER ALL;
INSERT INTO trigger_table VALUES (1, 'trigger disabled');
SELECT value, count(*) FROM trigger_table GROUP BY value ORDER BY value;
ALTER TABLE trigger_table ENABLE TRIGGER ALL;
INSERT INTO trigger_table VALUES (1, 'trigger disabled');
SELECT value, count(*) FROM trigger_table GROUP BY value ORDER BY value;
DROP TABLE trigger_table;
-- test ALTER TABLE ALL IN TABLESPACE
-- we expect that it will warn out
\set tablespace_location :abs_srcdir '/data'
CREATE TABLESPACE super_fast_ssd LOCATION :'tablespace_location';
ALTER TABLE ALL IN TABLESPACE pg_default SET TABLESPACE super_fast_ssd;
ALTER TABLE ALL IN TABLESPACE super_fast_ssd SET TABLESPACE pg_default;
DROP TABLESPACE super_fast_ssd;
-- Cleanup the table and its shards
SET citus.enable_ddl_propagation to true;
CREATE USER alter_table_owner WITH LOGIN;
GRANT USAGE ON SCHEMA public TO alter_table_owner;
GRANT USAGE ON SCHEMA multi_alter_table_statements TO alter_table_owner;
\c - alter_table_owner - :master_port
-- should not be able to access table without permission
SELECT count(*) FROM multi_alter_table_statements.lineitem_alter;
-- should not be able to drop the table as non table owner
DROP TABLE multi_alter_table_statements.lineitem_alter;
\c - postgres - :master_port
ALTER TABLE multi_alter_table_statements.lineitem_alter OWNER TO alter_table_owner;
\c - alter_table_owner - :master_port
-- should be able to query the table as table owner
SELECT count(*) FROM multi_alter_table_statements.lineitem_alter;
-- should be able to drop the table as table owner
DROP TABLE multi_alter_table_statements.lineitem_alter;
-- check that nothing's left over on workers, other than the leftover shard created
-- during the unsuccessful COPY
\c - postgres - :worker_1_port
SELECT relname FROM pg_class WHERE relname LIKE 'lineitem_alter%';
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 235000;
-- drop the roles created
REVOKE ALL ON SCHEMA PUBLIC FROM alter_table_owner;
REVOKE ALL ON SCHEMA multi_alter_table_statements FROM alter_table_owner;
DROP ROLE alter_table_owner;
-- Test alter table with drop table in the same transaction
BEGIN;
CREATE TABLE test_table_1(id int);
SELECT create_distributed_table('test_table_1','id');
ALTER TABLE test_table_1 ADD CONSTRAINT u_key UNIQUE(id);
DROP TABLE test_table_1;
END;
-- There should be no test_table_1 shard on workers
\c - - - :worker_1_port
SELECT relname FROM pg_class WHERE relname LIKE 'test_table_1%';
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 236000;
-- verify logged info is propagated to workers when distributing the table
CREATE TABLE logged_test(id int);
ALTER TABLE logged_test SET UNLOGGED;
SELECT create_distributed_table('logged_test', 'id');
\c - - - :worker_1_port
SELECT relname, CASE relpersistence WHEN 'u' THEN 'unlogged' WHEN 'p' then 'logged' ELSE 'unknown' END AS logged_info FROM pg_class WHERE relname ~ 'logged_test_' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 237000;
-- verify SET LOGGED/UNLOGGED works after distributing the table
ALTER TABLE logged_test SET LOGGED;
SELECT relname, CASE relpersistence WHEN 'u' THEN 'unlogged' WHEN 'p' then 'logged' ELSE 'unknown' END AS logged_info FROM pg_class WHERE relname ~ 'logged_test*' ORDER BY relname;
\c - - - :worker_1_port
SELECT relname, CASE relpersistence WHEN 'u' THEN 'unlogged' WHEN 'p' then 'logged' ELSE 'unknown' END AS logged_info FROM pg_class WHERE relname ~ 'logged_test_' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 238000;
ALTER TABLE logged_test SET UNLOGGED;
SELECT relname, CASE relpersistence WHEN 'u' THEN 'unlogged' WHEN 'p' then 'logged' ELSE 'unknown' END AS logged_info FROM pg_class WHERE relname ~ 'logged_test*' ORDER BY relname;
\c - - - :worker_1_port
SELECT relname, CASE relpersistence WHEN 'u' THEN 'unlogged' WHEN 'p' then 'logged' ELSE 'unknown' END AS logged_info FROM pg_class WHERE relname ~ 'logged_test_' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 239000;
DROP TABLE logged_test;
-- Test WITH options on a normal simple hash-distributed table
CREATE TABLE hash_dist(id bigint primary key, f1 text) WITH (fillfactor=40);
SELECT create_distributed_table('hash_dist','id');
-- verify that the storage options made it to the table definitions
SELECT relname, reloptions FROM pg_class WHERE relname = 'hash_dist';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relkind = 'r' AND relname LIKE 'hash_dist_%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 240000;
-- verify that we can set and reset index storage parameters
ALTER INDEX hash_dist_pkey SET(fillfactor=40);
SELECT relname, reloptions FROM pg_class WHERE relname = 'hash_dist_pkey';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'hash_dist_pkey_%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 241000;
ALTER INDEX hash_dist_pkey RESET(fillfactor);
SELECT relname, reloptions FROM pg_class WHERE relname = 'hash_dist_pkey';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'hash_dist_pkey_%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 242000;
-- verify error message on ALTER INDEX, SET TABLESPACE is unsupported
ALTER INDEX hash_dist_pkey SET TABLESPACE foo;
-- verify that we can add indexes with new storage options
CREATE UNIQUE INDEX another_index ON hash_dist(id) WITH (fillfactor=50);
-- show the index and its storage options on coordinator, then workers
SELECT relname, reloptions FROM pg_class WHERE relname = 'another_index';
\c - - - :worker_1_port
SELECT relname, reloptions FROM pg_class WHERE relname LIKE 'another_index_%' ORDER BY relname;
\c - - - :master_port
SET search_path TO multi_alter_table_statements, public;
SET citus.next_shard_id TO 243000;
-- get rid of the index
DROP INDEX another_index;
-- check if we fail properly when a column with un-supported constraint is added
-- UNIQUE, PRIMARY KEY on non-distribution column is not supported
-- CHECK, FOREIGN KEY, UNIQE, PRIMARY KEY cannot be added together with ADD COLUMN
SET citus.shard_replication_factor TO 1;
CREATE TABLE test_table_1(id int);
SELECT create_distributed_table('test_table_1', 'id');
ALTER TABLE test_table_1 ADD COLUMN test_col int UNIQUE;
ALTER TABLE test_table_1 ADD COLUMN test_col int PRIMARY KEY;
ALTER TABLE test_table_1 ADD COLUMN test_col int CHECK (test_col > 3);
CREATE TABLE reference_table(i int UNIQUE);
SELECT create_reference_table('reference_table');
ALTER TABLE test_table_1 ADD COLUMN test_col_1 int REFERENCES reference_table(i) ON DELETE CASCADE;
ALTER TABLE test_table_1 ADD COLUMN test_col_2 int REFERENCES reference_table(i) ON DELETE CASCADE ON UPDATE SET NULL;
SELECT (groupid = 0) AS is_coordinator, result FROM run_command_on_all_nodes(
$$SELECT get_grouped_fkey_constraints FROM get_grouped_fkey_constraints('multi_alter_table_statements.test_table_1')$$
)
JOIN pg_dist_node USING (nodeid)
ORDER BY is_coordinator DESC, result;
BEGIN;
SET LOCAL client_min_messages TO WARNING;
DROP TABLE reference_table CASCADE;
COMMIT;
CREATE TABLE referenced_table(i int UNIQUE);
SELECT create_distributed_table('referenced_table', 'i');
ALTER TABLE test_table_1 ADD COLUMN test_col_3 int REFERENCES referenced_table(i);
DROP TABLE referenced_table, test_table_1;
-- Check sequence propagate its own dependencies while adding a column
CREATE TABLE table_without_sequence(a int);
SELECT create_distributed_table('table_without_sequence', 'a');
CREATE SCHEMA test_schema_for_sequence_propagation;
CREATE SEQUENCE test_schema_for_sequence_propagation.seq_10;
ALTER TABLE table_without_sequence ADD COLUMN x BIGINT DEFAULT nextval('test_schema_for_sequence_propagation.seq_10');
-- Should be distributed along with the sequence
SELECT pg_identify_object_as_address(classid, objid, objsubid) from pg_catalog.pg_dist_object WHERE objid IN ('test_schema_for_sequence_propagation.seq_10'::regclass);
SELECT pg_identify_object_as_address(classid, objid, objsubid) from pg_catalog.pg_dist_object WHERE objid IN ('test_schema_for_sequence_propagation'::regnamespace);
-- Bug: https://github.com/citusdata/citus/issues/7378
-- Create a reference table
CREATE TABLE tbl_ref_mats(row_id integer primary key);
INSERT INTO tbl_ref_mats VALUES (1), (2);
SELECT create_reference_table('tbl_ref_mats');
-- Create a distributed table
CREATE TABLE tbl_dist_mats(series_id integer);
INSERT INTO tbl_dist_mats VALUES (1), (1), (2), (2);
SELECT create_distributed_table('tbl_dist_mats', 'series_id');
-- Create a view that joins the distributed table with the reference table on the distribution key.
CREATE VIEW vw_citus_views as
SELECT d.series_id FROM tbl_dist_mats d JOIN tbl_ref_mats r ON d.series_id = r.row_id;
-- The view initially works fine
SELECT * FROM vw_citus_views ORDER BY 1;
-- Now, alter the table
ALTER TABLE tbl_ref_mats ADD COLUMN category1 varchar(50);
SELECT * FROM vw_citus_views ORDER BY 1;
ALTER TABLE tbl_ref_mats ADD COLUMN category2 varchar(50);
SELECT * FROM vw_citus_views ORDER BY 1;
ALTER TABLE tbl_ref_mats DROP COLUMN category1;
SELECT * FROM vw_citus_views ORDER BY 1;
SET client_min_messages TO WARNING;
DROP SCHEMA test_schema_for_sequence_propagation CASCADE;
DROP TABLE table_without_sequence;
DROP SCHEMA multi_alter_table_statements CASCADE;