diff --git a/acceptance/shared/cases.go b/acceptance/shared/cases.go index dff58017..3d10bba6 100644 --- a/acceptance/shared/cases.go +++ b/acceptance/shared/cases.go @@ -78,8 +78,7 @@ CREATE TABLE my_columnar_table -- convert to columnar SELECT columnar.alter_table_set_access_method('my_table', 'columnar'); -- back to row - -- TODO: reenable this after it's supported - -- SELECT alter_table_set_access_method('my_table', 'heap'); + SELECT columnar.alter_table_set_access_method('my_table', 'heap'); `, }, { diff --git a/columnar/src/backend/columnar/sql/columnar--11.1-3--11.1-4.sql b/columnar/src/backend/columnar/sql/columnar--11.1-3--11.1-4.sql index 74a9fc80..2255b7f0 100644 --- a/columnar/src/backend/columnar/sql/columnar--11.1-3--11.1-4.sql +++ b/columnar/src/backend/columnar/sql/columnar--11.1-3--11.1-4.sql @@ -1,6 +1,8 @@ -- columnar--11.1-3--11.1-4.sql +#include "udfs/alter_table_set_access_method/11.1-4.sql" + -- Operators with vectorized execution -- char diff --git a/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-4.sql b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-4.sql new file mode 100644 index 00000000..dfb8e20b --- /dev/null +++ b/columnar/src/backend/columnar/sql/udfs/alter_table_set_access_method/11.1-4.sql @@ -0,0 +1,227 @@ +DROP FUNCTION IF EXISTS columnar.alter_table_set_access_method; + +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; + + 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; + + -- 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) 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) 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 <> '') 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 AND tablename = tbl_name + + AND + + 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) + + 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 %I (LIKE %I.%I + 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); + + -- Drop original table + + EXECUTE FORMAT('DROP TABLE %I'::text, tbl_name); + + -- Rename new table to original name + + EXECUTE FORMAT('ALTER TABLE %I RENAME TO %I;'::text, temp_tbl_name, 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 e6e94fba..dfb8e20b 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 @@ -1,3 +1,5 @@ +DROP FUNCTION IF EXISTS columnar.alter_table_set_access_method; + CREATE OR REPLACE FUNCTION columnar.alter_table_set_access_method(t TEXT, method TEXT) RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ @@ -9,12 +11,12 @@ DECLARE tbl_name TEXT; tbl_array TEXT[] = (parse_ident(t)); tbl_oid INT; + tbl_am_oid INT; temp_tbl_name TEXT; trigger_list_definition TEXT[]; trigger TEXT; - index_oid_list TEXT[]; index_list_definition TEXT[]; idx TEXT; @@ -35,9 +37,9 @@ BEGIN RETURN 0; END CASE; - -- Allow only convert to columnar access method + -- Allow only convert to columnar / heap access method - IF method NOT IN ('columnar') THEN + IF method NOT IN ('columnar', 'heap') THEN RAISE WARNING 'Cannot convert table: Allowed access methods are heap and columnar.'; RETURN 0; END IF; @@ -57,6 +59,25 @@ BEGIN 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) THEN @@ -83,7 +104,6 @@ BEGIN 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 @@ -128,18 +148,17 @@ BEGIN INTO index_list_definition; - - -- Generate random name for columnar table + -- Generate random name for new table SELECT 't_' || substr(md5(random()::text), 0, 25) INTO temp_tbl_name; - -- Create new columnar table + -- Create new table EXECUTE FORMAT(' CREATE TABLE %I (LIKE %I.%I INCLUDING GENERATED INCLUDING DEFAULTS - ) USING columnar'::text, temp_tbl_name, tbl_schema, tbl_name); + ) USING %s'::text, temp_tbl_name, tbl_schema, tbl_name, method); -- Insert all data from original table @@ -149,7 +168,7 @@ BEGIN EXECUTE FORMAT('DROP TABLE %I'::text, tbl_name); - -- Rename columnar table to original name + -- Rename new table to original name EXECUTE FORMAT('ALTER TABLE %I RENAME TO %I;'::text, temp_tbl_name, tbl_name); 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 31e57bf3..805c9ebd 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 @@ -1,7 +1,7 @@ -- -- Testing alter_table_set_access_method -- --- 1. check conversion of 'normal' tables +-- 1. check conversion of 'heap' table to 'columnar' CREATE TABLE t (a INT) USING heap; SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); count @@ -35,7 +35,41 @@ SELECT COUNT(*) = 3 FROM t; (1 row) DROP TABLE t; --- 2. check conversion of tables with trigger +-- 2. check conversion of 'columnar' table to 'heap' +CREATE TABLE t (a INT) USING columnar; +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + count +------- + 1 +(1 row) + +INSERT INTO t VALUES (1),(2),(3); +SELECT COUNT(*) = 3 FROM t; + ?column? +---------- + t +(1 row) + +SELECT columnar.alter_table_set_access_method('t', 'heap'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +SELECT COUNT(*) = 3 FROM t; + ?column? +---------- + t +(1 row) + +DROP TABLE t; +-- 3. check conversion of tables with trigger CREATE TABLE t (a INT) USING heap; CREATE or REPLACE FUNCTION trs_before() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN @@ -105,7 +139,37 @@ INSERT INTO t VALUES (1); NOTICE: BEFORE STATEMENT INSERT NOTICE: BEFORE ROW INSERT: (1) NOTICE: AFTER STATEMENT INSERT --- 3. check conversion of tables with indexes which can be created with columnar +-- Convert back to 'heap' +SELECT columnar.alter_table_set_access_method('t', 'heap'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +SELECT COUNT(*) = 3 FROM pg_trigger WHERE tgrelid = 't'::regclass::oid; + ?column? +---------- + t +(1 row) + +INSERT INTO t VALUES (1); +NOTICE: BEFORE STATEMENT INSERT +NOTICE: BEFORE ROW INSERT: (1) +NOTICE: AFTER STATEMENT INSERT +SELECT COUNT(*) = 3 FROM t; + ?column? +---------- + t +(1 row) + +DROP TABLE t; +-- 4. check conversion of tables with indexes which can be created with columnar CREATE TABLE index_table (a INT) USING heap; CREATE INDEX idx1 ON index_table (a); -- also create an index with statistics @@ -117,7 +181,7 @@ SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT 1 (1 row) -SELECT indexname FROM pg_indexes WHERE tablename = 'index_table'; +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; indexname ----------- idx1 @@ -136,7 +200,27 @@ SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT 1 (1 row) -SELECT indexname FROM pg_indexes WHERE tablename = 'index_table'; +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; + indexname +----------- + idx1 + idx2 +(2 rows) + +-- Convert back to 'heap' +SELECT columnar.alter_table_set_access_method('index_table', 'heap'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; indexname ----------- idx1 @@ -144,7 +228,7 @@ SELECT indexname FROM pg_indexes WHERE tablename = 'index_table'; (2 rows) DROP TABLE index_table; --- 4. Convert table with indexes and constraints +-- 5. Convert table with indexes and constraints CREATE TABLE tbl ( c1 CIRCLE, c2 TEXT, @@ -206,13 +290,45 @@ SELECT COUNT(1) FROM pg_class WHERE relname = 'tbl' AND relam = (SELECT oid FROM 1 (1 row) -SELECT indexname FROM pg_indexes WHERE tablename = 'tbl'; +SELECT indexname FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname; indexname -------------- + tbl_a_p_excl tbl_hash + tbl_pkey + tbl_unique +(4 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_a_p_excl + tbl_hash tbl_pkey + tbl_unique (4 rows) SELECT conname FROM pg_constraint @@ -226,7 +342,7 @@ ORDER BY conname; (3 rows) DROP TABLE tbl; --- 5. check non existing table +-- 6. Check non existing table SELECT columnar.alter_table_set_access_method('some_test', 'columnar'); WARNING: Table public.some_test does not exist. alter_table_set_access_method @@ -234,9 +350,8 @@ WARNING: Table public.some_test does not exist. f (1 row) --- 6. check if method is different than columnar +-- 7. Check if method is different than columnar / heap CREATE TABLE t(a INT); -ERROR: relation "t" already exists SELECT columnar.alter_table_set_access_method('t', 'other'); WARNING: Cannot convert table: Allowed access methods are heap and columnar. alter_table_set_access_method @@ -245,7 +360,7 @@ WARNING: Cannot convert table: Allowed access methods are heap and columnar. (1 row) DROP TABLE t; --- 7. check if table have identity columns +-- 8. Check if table have identity columns CREATE TABLE identity_cols_test (a INT, b INT GENERATED BY DEFAULT AS IDENTITY (INCREMENT BY 42)); SELECT columnar.alter_table_set_access_method('identity_cols_test', 'columnar'); WARNING: Cannot convert table: table public.identity_cols_test must not use GENERATED ... AS IDENTITY. @@ -255,3 +370,60 @@ WARNING: Cannot convert table: table public.identity_cols_test must not use GEN (1 row) DROP TABLE identity_cols_test; +-- 9. Check conversion to same AM +CREATE TABLE t(a INT); +-- fail (heap -> heap) +SELECT columnar.alter_table_set_access_method('t', 'heap'); +WARNING: Cannot convert table: conversion to same access method. + alter_table_set_access_method +------------------------------- + f +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +-- ok (heap -> columnar) +SELECT columnar.alter_table_set_access_method('t', 'columnar'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + count +------- + 1 +(1 row) + +-- fail (columnar -> columnar) +SELECT columnar.alter_table_set_access_method('t', 'columnar'); +WARNING: Cannot convert table: conversion to same access method. + alter_table_set_access_method +------------------------------- + f +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + count +------- + 1 +(1 row) + +-- ok (columnar -> heap) +SELECT columnar.alter_table_set_access_method('t', 'heap'); + alter_table_set_access_method +------------------------------- + t +(1 row) + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + count +------- + 1 +(1 row) + +DROP TABLE t; 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 d9091b37..dab9b3fb 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 @@ -2,7 +2,7 @@ -- Testing alter_table_set_access_method -- --- 1. check conversion of 'normal' tables +-- 1. check conversion of 'heap' table to 'columnar' CREATE TABLE t (a INT) USING heap; @@ -20,7 +20,25 @@ SELECT COUNT(*) = 3 FROM t; DROP TABLE t; --- 2. check conversion of tables with trigger +-- 2. check conversion of 'columnar' table to 'heap' + +CREATE TABLE t (a INT) USING columnar; + +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + +INSERT INTO t VALUES (1),(2),(3); + +SELECT COUNT(*) = 3 FROM t; + +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'); + +SELECT COUNT(*) = 3 FROM t; + +DROP TABLE t; + +-- 3. check conversion of tables with trigger CREATE TABLE t (a INT) USING heap; @@ -77,8 +95,21 @@ SELECT COUNT(*) = 3 FROM pg_trigger WHERE tgrelid = 't'::regclass::oid; INSERT INTO t VALUES (1); +-- Convert back to 'heap' + +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'); --- 3. check conversion of tables with indexes which can be created with columnar +SELECT COUNT(*) = 3 FROM pg_trigger WHERE tgrelid = 't'::regclass::oid; + +INSERT INTO t VALUES (1); + +SELECT COUNT(*) = 3 FROM t; + +DROP TABLE t; + +-- 4. check conversion of tables with indexes which can be created with columnar CREATE TABLE index_table (a INT) USING heap; @@ -91,17 +122,25 @@ ALTER INDEX idx2 ALTER COLUMN 1 SET STATISTICS 300; SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); -SELECT indexname FROM pg_indexes WHERE tablename = 'index_table'; +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; SELECT columnar.alter_table_set_access_method('index_table', 'columnar'); SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); -SELECT indexname FROM pg_indexes WHERE tablename = 'index_table'; +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; + +-- Convert back to 'heap' + +SELECT columnar.alter_table_set_access_method('index_table', 'heap'); + +SELECT COUNT(1) FROM pg_class WHERE relname = 'index_table' AND relam = (SELECT oid FROM pg_am WHERE amname = 'heap'); + +SELECT indexname FROM pg_indexes WHERE tablename = 'index_table' ORDER BY indexname; DROP TABLE index_table; --- 4. Convert table with indexes and constraints +-- 5. Convert table with indexes and constraints CREATE TABLE tbl ( c1 CIRCLE, @@ -138,7 +177,19 @@ 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'; +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 @@ -146,15 +197,37 @@ ORDER BY conname; DROP TABLE tbl; --- 5. check non existing table +-- 6. Check non existing table SELECT columnar.alter_table_set_access_method('some_test', 'columnar'); --- 6. check if method is different than columnar +-- 7. Check if method is different than columnar / heap CREATE TABLE t(a INT); SELECT columnar.alter_table_set_access_method('t', 'other'); DROP TABLE t; --- 7. check if table have identity columns +-- 8. Check if table have identity columns CREATE TABLE identity_cols_test (a INT, b INT GENERATED BY DEFAULT AS IDENTITY (INCREMENT BY 42)); SELECT columnar.alter_table_set_access_method('identity_cols_test', 'columnar'); -DROP TABLE identity_cols_test; \ No newline at end of file +DROP TABLE identity_cols_test; + +-- 9. Check conversion to same AM + +CREATE TABLE t(a INT); + +-- fail (heap -> heap) +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'); + +-- ok (heap -> columnar) +SELECT columnar.alter_table_set_access_method('t', 'columnar'); +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + +-- fail (columnar -> columnar) +SELECT columnar.alter_table_set_access_method('t', 'columnar'); +SELECT COUNT(1) FROM pg_class WHERE relname = 't' AND relam = (SELECT oid FROM pg_am WHERE amname = 'columnar'); + +-- ok (columnar -> heap) +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