From a935675c5311e72aeba51d11ddbf7ced0a558a72 Mon Sep 17 00:00:00 2001 From: mkaruza Date: Thu, 1 Feb 2024 18:20:49 +0100 Subject: [PATCH] [columnar] Case sensitive columnar.alter_table_set_access_method (#237) * Handle case sensitive table and schema names --- .../src/backend/columnar/columnar.control | 2 +- .../sql/columnar--11.1-10--11.1-11.sql | 1 + .../alter_table_set_access_method/11.1-11.sql | 251 ++++++++++++++++++ .../alter_table_set_access_method/latest.sql | 41 ++- ...columnar_alter_table_set_access_method.out | 116 ++++++++ ...columnar_alter_table_set_access_method.sql | 59 +++- 6 files changed, 458 insertions(+), 12 deletions(-) create mode 100644 columnar/src/backend/columnar/sql/columnar--11.1-10--11.1-11.sql create mode 100644 columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-11.sql diff --git a/columnar/src/backend/columnar/columnar.control b/columnar/src/backend/columnar/columnar.control index 4fed3c92..3d2e7793 100644 --- a/columnar/src/backend/columnar/columnar.control +++ b/columnar/src/backend/columnar/columnar.control @@ -1,4 +1,4 @@ comment = 'Hydra Columnar extension' -default_version = '11.1-10' +default_version = '11.1-11' module_pathname = '$libdir/columnar' relocatable = false diff --git a/columnar/src/backend/columnar/sql/columnar--11.1-10--11.1-11.sql b/columnar/src/backend/columnar/sql/columnar--11.1-10--11.1-11.sql new file mode 100644 index 00000000..829d1cf2 --- /dev/null +++ b/columnar/src/backend/columnar/sql/columnar--11.1-10--11.1-11.sql @@ -0,0 +1 @@ +#include "udfs/alter_table_set_access_method/11.1-11.sql" \ No newline at end of file diff --git a/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-11.sql b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-11.sql new file mode 100644 index 00000000..6136335e --- /dev/null +++ b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-11.sql @@ -0,0 +1,251 @@ +CREATE OR REPLACE FUNCTION columnar.alter_table_set_access_method(t TEXT, method TEXT) + RETURNS BOOLEAN LANGUAGE plpgsql +AS $func$ + +DECLARE + + tbl_exists BOOLEAN; + tbl_schema TEXT = 'public'; + tbl_name TEXT; + tbl_array TEXT[] = (parse_ident(t)); + tbl_oid INT; + tbl_am_oid INT; + temp_tbl_name TEXT; + + is_case_sensitive BOOLEAN; + tbl_name_original TEXT; + tbl_schema_original TEXT; + + trigger_list_definition TEXT[]; + trigger TEXT; + + index_list_definition TEXT[]; + idx TEXT; + + constraint_list_name_and_definition TEXT[]; + constraint_name_and_definition TEXT; + constraint_name_and_definition_split TEXT[]; + +BEGIN + + CASE + WHEN CARDINALITY(tbl_array) = 1 THEN + SELECT tbl_array[1] INTO tbl_name; + WHEN CARDINALITY(tbl_array) = 2 THEN + SELECT tbl_array[1] INTO tbl_schema; + SELECT tbl_array[2] INTO tbl_name; + ELSE + RAISE WARNING 'Argument should provided as table or schema.table.'; + RETURN 0; + END CASE; + + -- Allow only convert to columnar / heap access method + + IF method NOT IN ('columnar', 'heap') THEN + RAISE WARNING 'Cannot convert table: Allowed access methods are heap and columnar.'; + RETURN 0; + END IF; + + -- Check if table exists + + SELECT EXISTS + (SELECT FROM pg_catalog.pg_tables WHERE schemaname = tbl_schema AND tablename = tbl_name) + INTO tbl_exists; + + IF tbl_exists = False THEN + RAISE WARNING 'Table %.% does not exist.', tbl_schema, tbl_name; + RETURN 0; + END IF; + + -- Case senstivitiy + + SELECT EXISTS (SELECT regexp_matches(tbl_name,'[A-Z]')) INTO is_case_sensitive; + + SELECT tbl_name INTO tbl_name_original; + + IF is_case_sensitive = True THEN + SELECT quote_ident(tbl_name) INTO tbl_name; + END IF; + + SELECT EXISTS (SELECT regexp_matches(tbl_schema,'[A-Z]')) INTO is_case_sensitive; + + SELECT tbl_schema INTO tbl_schema_original; + + IF is_case_sensitive = True THEN + SELECT quote_ident(tbl_schema) INTO tbl_schema; + END IF; + + -- Get table OID + + EXECUTE FORMAT('SELECT %L::regclass::oid'::text, tbl_schema || '.' || tbl_name) INTO tbl_oid; + + -- Get table AM oid + + SELECT relam FROM pg_class WHERE oid = tbl_oid INTO tbl_am_oid; + + -- Check that table is heap or columnar + + IF (tbl_am_oid != (SELECT oid FROM pg_am WHERE amname = 'columnar')) AND + (tbl_am_oid != (SELECT oid FROM pg_am WHERE amname = 'heap')) THEN + RAISE WARNING 'Cannot convert table: table %.% is not heap or colummnar', tbl_schema, tbl_name; + RETURN 0; + END IF; + + -- Check that we can convert only from 'heap' to 'columnar' and vice versa + + IF tbl_am_oid = (SELECT oid FROM pg_am WHERE amname = method) THEN + RAISE WARNING 'Cannot convert table: conversion to same access method.'; + RETURN 0; + END IF; + + -- Check if table has FOREIGN KEY + + IF (SELECT COUNT(1) FROM pg_constraint WHERE contype = 'f' AND conrelid = tbl_oid) > 0 THEN + RAISE WARNING 'Cannot convert table: table %.% has a FOREIGN KEY constraint.', tbl_schema, tbl_name; + RETURN 0; + END IF; + + -- Check if table is REFERENCED by FOREIGN KEY + + IF (SELECT COUNT(1) FROM pg_constraint WHERE contype = 'f' AND confrelid = tbl_oid) > 0 THEN + RAISE WARNING 'Cannot convert table: table %.% is referenced by FOREIGN KEY.', tbl_schema, tbl_name; + RETURN 0; + END IF; + + -- Check if table has identity columns + + IF (SELECT COUNT(1) FROM pg_attribute WHERE attrelid = tbl_oid AND attidentity <> '') > 0 THEN + RAISE WARNING 'Cannot convert table: table %.% must not use GENERATED ... AS IDENTITY.', tbl_schema, tbl_name; + RETURN 0; + END IF; + + -- Collect triggers definitions + + SELECT ARRAY_AGG(pg_get_triggerdef(oid)) FROM pg_trigger + WHERE tgrelid = tbl_oid INTO trigger_list_definition; + + -- Collect constraint names and definitions (delimiter is `?`) + -- Search for constraints that depend on index AM which is supported by columnar AM + + SELECT ARRAY_AGG(pg_constraint.conname || '?' || pg_get_constraintdef(pg_constraint.oid)) + + FROM pg_constraint, pg_class + + WHERE + pg_constraint.conindid = pg_class.oid + AND + pg_constraint.conrelid = tbl_oid + AND + pg_class.relam IN (SELECT oid FROM pg_am WHERE amname IN ('btree', 'hash')) + + INTO constraint_list_name_and_definition; + + -- Collect index definitions which are not constraints + + SELECT ARRAY_AGG(indexdef) FROM pg_indexes + + WHERE + + schemaname = tbl_schema_original AND tablename = tbl_name_original + + AND + + quote_ident(indexname)::regclass::oid IN + ( + SELECT indexrelid FROM pg_index + + WHERE + indexrelid IN + (SELECT quote_ident(indexname)::regclass::oid FROM pg_indexes + WHERE schemaname = tbl_schema_original AND tablename = tbl_name_original) + + AND + + indexrelid NOT IN + (SELECT conindid FROM pg_constraint + WHERE pg_constraint.conrelid = tbl_oid) + ) + + INTO index_list_definition; + + -- Generate random name for new table + + SELECT 't_' || substr(md5(random()::text), 0, 25) INTO temp_tbl_name; + + -- Create new table + + EXECUTE FORMAT(' + CREATE TABLE %s (LIKE %s.%s + INCLUDING GENERATED + INCLUDING DEFAULTS + ) USING %s'::text, temp_tbl_name, tbl_schema, tbl_name, method); + + -- Insert all data from original table + + EXECUTE FORMAT('INSERT INTO %s SELECT * FROM %s.%s'::text, temp_tbl_name, tbl_schema, tbl_name); + + -- Drop original table + + EXECUTE FORMAT('DROP TABLE %s'::text, tbl_name); + + -- Rename new table to original name + + EXECUTE FORMAT('ALTER TABLE %s RENAME TO %s;'::text, temp_tbl_name, tbl_name); + + -- Since we inserted rows before they are not flushed so trigger flushing + + EXECUTE FORMAT('SELECT COUNT(1) FROM %s LIMIT 1;'::text, tbl_name); + + -- Set indexes + + IF CARDINALITY(index_list_definition) <> 0 THEN + FOREACH idx IN ARRAY index_list_definition + LOOP + BEGIN + EXECUTE idx; + EXCEPTION WHEN feature_not_supported THEN + RAISE WARNING 'Index `%` cannot be created.', idx; + END; + END LOOP; + END IF; + + -- Set constraints + + IF CARDINALITY(constraint_list_name_and_definition) <> 0 THEN + FOREACH constraint_name_and_definition IN ARRAY constraint_list_name_and_definition + LOOP + SELECT string_to_array(constraint_name_and_definition, '?') INTO constraint_name_and_definition_split; + BEGIN + EXECUTE 'ALTER TABLE ' || tbl_name || ' ADD CONSTRAINT ' + || constraint_name_and_definition_split[1] || ' ' + || constraint_name_and_definition_split[2]; + EXCEPTION WHEN feature_not_supported THEN + RAISE WARNING 'Constraint `%` cannot be added.', constraint_name_and_definition_split[2]; + END; + END LOOP; + END IF; + + -- Set triggers + + IF CARDINALITY(trigger_list_definition) <> 0 THEN + FOREACH trigger IN ARRAY trigger_list_definition + LOOP + BEGIN + EXECUTE trigger; + EXCEPTION WHEN feature_not_supported THEN + RAISE WARNING 'Trigger `%` cannot be applied.', trigger; + RAISE WARNING + 'Foreign keys and AFTER ROW triggers are not supported for columnar tables.' + ' Consider an AFTER STATEMENT trigger instead.'; + END; + END LOOP; + END IF; + + RETURN 1; + +END; + +$func$; + +COMMENT ON FUNCTION columnar.alter_table_set_access_method(t text, method text) + IS 'alters a table''s access method'; \ No newline at end of file diff --git a/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/latest.sql b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/latest.sql index 0a798ee3..6136335e 100644 --- a/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/latest.sql +++ b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/latest.sql @@ -12,6 +12,10 @@ DECLARE tbl_am_oid INT; temp_tbl_name TEXT; + is_case_sensitive BOOLEAN; + tbl_name_original TEXT; + tbl_schema_original TEXT; + trigger_list_definition TEXT[]; trigger TEXT; @@ -53,6 +57,24 @@ BEGIN RETURN 0; END IF; + -- Case senstivitiy + + SELECT EXISTS (SELECT regexp_matches(tbl_name,'[A-Z]')) INTO is_case_sensitive; + + SELECT tbl_name INTO tbl_name_original; + + IF is_case_sensitive = True THEN + SELECT quote_ident(tbl_name) INTO tbl_name; + END IF; + + SELECT EXISTS (SELECT regexp_matches(tbl_schema,'[A-Z]')) INTO is_case_sensitive; + + SELECT tbl_schema INTO tbl_schema_original; + + IF is_case_sensitive = True THEN + SELECT quote_ident(tbl_schema) INTO tbl_schema; + END IF; + -- Get table OID EXECUTE FORMAT('SELECT %L::regclass::oid'::text, tbl_schema || '.' || tbl_name) INTO tbl_oid; @@ -124,18 +146,18 @@ BEGIN WHERE - schemaname = tbl_schema AND tablename = tbl_name + schemaname = tbl_schema_original AND tablename = tbl_name_original AND - indexname::regclass::oid IN + quote_ident(indexname)::regclass::oid IN ( SELECT indexrelid FROM pg_index WHERE indexrelid IN - (SELECT indexname::regclass::oid FROM pg_indexes - WHERE schemaname = tbl_schema AND tablename = tbl_name) + (SELECT quote_ident(indexname)::regclass::oid FROM pg_indexes + WHERE schemaname = tbl_schema_original AND tablename = tbl_name_original) AND @@ -153,27 +175,26 @@ BEGIN -- Create new table EXECUTE FORMAT(' - CREATE TABLE %I (LIKE %I.%I + CREATE TABLE %s (LIKE %s.%s INCLUDING GENERATED INCLUDING DEFAULTS ) USING %s'::text, temp_tbl_name, tbl_schema, tbl_name, method); -- Insert all data from original table - EXECUTE FORMAT('INSERT INTO %I SELECT * FROM %I.%I'::text, temp_tbl_name, tbl_schema, tbl_name); + EXECUTE FORMAT('INSERT INTO %s SELECT * FROM %s.%s'::text, temp_tbl_name, tbl_schema, tbl_name); -- Drop original table - EXECUTE FORMAT('DROP TABLE %I'::text, tbl_name); + EXECUTE FORMAT('DROP TABLE %s'::text, tbl_name); -- Rename new table to original name - EXECUTE FORMAT('ALTER TABLE %I RENAME TO %I;'::text, temp_tbl_name, tbl_name); + EXECUTE FORMAT('ALTER TABLE %s RENAME TO %s;'::text, temp_tbl_name, tbl_name); -- Since we inserted rows before they are not flushed so trigger flushing - -- by running columnar scan - EXECUTE FORMAT('SELECT COUNT(1) FROM %I LIMIT 1;'::text, tbl_name); + EXECUTE FORMAT('SELECT COUNT(1) FROM %s LIMIT 1;'::text, tbl_name); -- Set indexes diff --git a/columnar/src/test/regress/expected/columnar_alter_table_set_access_method.out b/columnar/src/test/regress/expected/columnar_alter_table_set_access_method.out index 4d9087ba..7bb7feb5 100644 --- a/columnar/src/test/regress/expected/columnar_alter_table_set_access_method.out +++ b/columnar/src/test/regress/expected/columnar_alter_table_set_access_method.out @@ -429,3 +429,119 @@ SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM p (1 row) DROP TABLE t; +-- 10. Check case sensitivity +CREATE TABLE "tBl" ( + c1 CIRCLE, + "C2" TEXT, + i int4[], + p point, + a int, + EXCLUDE USING gist + (c1 WITH &&, ("C2"::circle) WITH &&) + WHERE (circle_center(c1) <> '(0,0)'), + EXCLUDE USING btree + (a WITH =) + INCLUDE(p) + WHERE ("C2" < 'astring') +); +CREATE INDEX "TBL_GIN" ON "tBl" USING gin (i); +CREATE INDEX tbl_gist ON "tBl" USING gist(p); +CREATE INDEX tbl_brin ON "tBl" USING brin (a) WITH (pages_per_range = 1); +CREATE INDEX tbl_hash ON "tBl" USING hash ("C2"); +ALTER TABLE "tBl" ADD CONSTRAINT tbl_unique UNIQUE ("C2"); +CREATE UNIQUE INDEX tbl_btree ON "tBl" USING btree (a); +ALTER TABLE "tBl" ADD CONSTRAINT tbl_pkey PRIMARY KEY USING INDEX tbl_btree; +NOTICE: ALTER TABLE / ADD CONSTRAINT USING INDEX will rename index "tbl_btree" to "tbl_pkey" +SELECT indexname, indexdef FROM pg_indexes +WHERE tablename = 'tBl' +ORDER BY indexname; + indexname | indexdef +----------------+----------------------------------------------------------------------------------------------------------------------------- + TBL_GIN | CREATE INDEX "TBL_GIN" ON public."tBl" USING gin (i) + tBl_a_p_excl | CREATE INDEX "tBl_a_p_excl" ON public."tBl" USING btree (a) INCLUDE (p) WHERE ("C2" < 'astring'::text) + tBl_c1_C2_excl | CREATE INDEX "tBl_c1_C2_excl" ON public."tBl" USING gist (c1, (("C2")::circle)) WHERE (circle_center(c1) <> '(0,0)'::point) + tbl_brin | CREATE INDEX tbl_brin ON public."tBl" USING brin (a) WITH (pages_per_range='1') + tbl_gist | CREATE INDEX tbl_gist ON public."tBl" USING gist (p) + tbl_hash | CREATE INDEX tbl_hash ON public."tBl" USING hash ("C2") + tbl_pkey | CREATE UNIQUE INDEX tbl_pkey ON public."tBl" USING btree (a) + tbl_unique | CREATE UNIQUE INDEX tbl_unique ON public."tBl" USING btree ("C2") +(8 rows) + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conrelid = '"tBl"'::regclass; + pg_get_constraintdef +--------------------------------------------------------------------------------------------------------- + EXCLUDE USING gist (c1 WITH &&, (("C2")::circle) WITH &&) WHERE ((circle_center(c1) <> '(0,0)'::point)) + EXCLUDE USING btree (a WITH =) INCLUDE (p) WHERE (("C2" < 'astring'::text)) + UNIQUE ("C2") + PRIMARY KEY (a) +(4 rows) + +SELECT columnar.alter_table_set_access_method('"tBl"', 'columnar'); +WARNING: Index `CREATE INDEX tbl_brin ON public."tBl" USING brin (a) WITH (pages_per_range='1')` cannot be created. + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 'tBl' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + count +------- + 1 +(1 row) + +SELECT indexname FROM pg_indexes WHERE tablename = 'tBl' ORDER BY indexname; + indexname +-------------- + TBL_GIN + tbl_a_p_excl + tbl_gist + tbl_hash + tbl_pkey + tbl_unique +(6 rows) + +SELECT conname FROM pg_constraint +WHERE conrelid = '"tBl"'::regclass +ORDER BY conname; + conname +-------------- + tbl_a_p_excl + tbl_pkey + tbl_unique +(3 rows) + +-- Convert back to 'heap' +SELECT columnar.alter_table_set_access_method('"tBl"', 'heap'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 'tBl' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +SELECT indexname FROM pg_indexes WHERE tablename = 'tBl' ORDER BY indexname; + indexname +-------------- + TBL_GIN + tbl_a_p_excl + tbl_gist + tbl_hash + tbl_pkey + tbl_unique +(6 rows) + +SELECT conname FROM pg_constraint +WHERE conrelid = '"tBl"'::regclass +ORDER BY conname; + conname +-------------- + tbl_a_p_excl + tbl_pkey + tbl_unique +(3 rows) + +DROP TABLE "tBl"; diff --git a/columnar/src/test/regress/sql/columnar_alter_table_set_access_method.sql b/columnar/src/test/regress/sql/columnar_alter_table_set_access_method.sql index dab9b3fb..a7c58161 100644 --- a/columnar/src/test/regress/sql/columnar_alter_table_set_access_method.sql +++ b/columnar/src/test/regress/sql/columnar_alter_table_set_access_method.sql @@ -230,4 +230,61 @@ SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM p SELECT columnar.alter_table_set_access_method('t', 'heap'); SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); -DROP TABLE t; \ No newline at end of file +DROP TABLE t; + +-- 10. Check case sensitivity + +CREATE TABLE "tBl" ( + c1 CIRCLE, + "C2" TEXT, + i int4[], + p point, + a int, + EXCLUDE USING gist + (c1 WITH &&, ("C2"::circle) WITH &&) + WHERE (circle_center(c1) <> '(0,0)'), + EXCLUDE USING btree + (a WITH =) + INCLUDE(p) + WHERE ("C2" < 'astring') +); + +CREATE INDEX "TBL_GIN" ON "tBl" USING gin (i); +CREATE INDEX tbl_gist ON "tBl" USING gist(p); +CREATE INDEX tbl_brin ON "tBl" USING brin (a) WITH (pages_per_range = 1); + +CREATE INDEX tbl_hash ON "tBl" USING hash ("C2"); +ALTER TABLE "tBl" ADD CONSTRAINT tbl_unique UNIQUE ("C2"); + +CREATE UNIQUE INDEX tbl_btree ON "tBl" USING btree (a); +ALTER TABLE "tBl" ADD CONSTRAINT tbl_pkey PRIMARY KEY USING INDEX tbl_btree; + +SELECT indexname, indexdef FROM pg_indexes +WHERE tablename = 'tBl' +ORDER BY indexname; + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conrelid = '"tBl"'::regclass; + +SELECT columnar.alter_table_set_access_method('"tBl"', 'columnar'); + +SELECT COUNT(1) FROM pg_class WHERE relname = 'tBl' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + +SELECT indexname FROM pg_indexes WHERE tablename = 'tBl' ORDER BY indexname; + +SELECT conname FROM pg_constraint +WHERE conrelid = '"tBl"'::regclass +ORDER BY conname; + +-- Convert back to 'heap' + +SELECT columnar.alter_table_set_access_method('"tBl"', 'heap'); + +SELECT COUNT(1) FROM pg_class WHERE relname = 'tBl' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + +SELECT indexname FROM pg_indexes WHERE tablename = 'tBl' ORDER BY indexname; + +SELECT conname FROM pg_constraint +WHERE conrelid = '"tBl"'::regclass +ORDER BY conname; + +DROP TABLE "tBl"; \ No newline at end of file