From 6f3bf88430f0c757e190313ee50de8e992ec3631 Mon Sep 17 00:00:00 2001 From: Konstantina Skovola Date: Mon, 14 Mar 2022 12:54:14 +0200 Subject: [PATCH] Fix ADD COLUMN IF NOT EXISTS error on compressed hypertable Stop throwing exception with message "column of relation already exists" when running the command ALTER TABLE ... ADD COLUMN IF NOT EXISTS ... on compressed hypertables. Fix #4087 --- tsl/src/compression/create.c | 28 +++++++- tsl/test/expected/compression_errors.out | 32 +++++++++ tsl/test/expected/dist_compression.out | 84 ++++++++++++++++++++++++ tsl/test/sql/compression_errors.sql | 22 +++++++ tsl/test/sql/dist_compression.sql | 39 +++++++++++ 5 files changed, 203 insertions(+), 2 deletions(-) diff --git a/tsl/src/compression/create.c b/tsl/src/compression/create.c index e3ef8aa2f30..ab4725e458e 100644 --- a/tsl/src/compression/create.c +++ b/tsl/src/compression/create.c @@ -923,24 +923,40 @@ disable_compression(Hypertable *ht, WithClauseResult *with_clause_options) } /* Add column to internal compression table */ -static void +static bool add_column_to_compression_table(Hypertable *compress_ht, CompressColInfo *compress_cols) { Oid compress_relid = compress_ht->main_table_relid; ColumnDef *coldef; AlterTableCmd *addcol_cmd; coldef = (ColumnDef *) linitial(compress_cols->coldeflist); + HeapTuple attTuple; + bool new_column = false; /* create altertable stmt to add column to the compressed hypertable */ Assert(TS_HYPERTABLE_IS_INTERNAL_COMPRESSION_TABLE(compress_ht)); addcol_cmd = makeNode(AlterTableCmd); addcol_cmd->subtype = AT_AddColumn; addcol_cmd->def = (Node *) coldef; - addcol_cmd->missing_ok = false; + addcol_cmd->missing_ok = true; + + attTuple = SearchSysCache2(ATTNAME, + ObjectIdGetDatum(compress_relid), + PointerGetDatum(coldef->colname)); + if (!HeapTupleIsValid(attTuple)) + { + /* the column doesn't exist yet */ + new_column = true; + } + else + { + ReleaseSysCache(attTuple); + } /* alter the table and add column */ AlterTableInternal(compress_relid, list_make1(addcol_cmd), true); modify_compressed_toast_table_storage(compress_cols, compress_relid); + return new_column; } /* Drop column from internal compression table */ @@ -1067,6 +1083,14 @@ tsl_process_compress_table_add_column(Hypertable *ht, ColumnDef *orig_def) coloid = LookupTypeNameOid(NULL, orig_typname, false); compresscolinfo_init_singlecolumn(&compress_cols, colname, coloid); + + FormData_hypertable_compression *ht_comp = + ts_hypertable_compression_get_by_pkey(ht->fd.id, colname); + /* don't add column if it already exists */ + if (ht_comp) + { + return; + } if (TS_HYPERTABLE_HAS_COMPRESSION_TABLE(ht)) { int32 compress_htid = ht->fd.compressed_hypertable_id; diff --git a/tsl/test/expected/compression_errors.out b/tsl/test/expected/compression_errors.out index fbaeda1e223..a1e33bf12d8 100644 --- a/tsl/test/expected/compression_errors.out +++ b/tsl/test/expected/compression_errors.out @@ -494,3 +494,35 @@ SELECT config FROM _timescaledb_config.bgw_job WHERE id = :compressjob_id; CALL run_job(:compressjob_id); ERROR: job 1001 has null config CONTEXT: PL/pgSQL function _timescaledb_internal.policy_compression(integer,jsonb) line 21 at RAISE +-- test ADD COLUMN IF NOT EXISTS +CREATE TABLE metric (time TIMESTAMPTZ NOT NULL, val FLOAT8 NOT NULL, dev_id INT4 NOT NULL); +SELECT create_hypertable('metric', 'time', 'dev_id', 10); + create_hypertable +---------------------- + (23,public,metric,t) +(1 row) + +ALTER TABLE metric SET ( +timescaledb.compress, +timescaledb.compress_segmentby = 'dev_id', +timescaledb.compress_orderby = 'time DESC' +); +INSERT INTO metric(time, val, dev_id) +SELECT s.*, 3.14+1, 1 +FROM generate_series('2021-08-17 00:00:00'::timestamp, + '2021-08-17 00:02:00'::timestamp, '1 s'::interval) s; +SELECT compress_chunk(show_chunks('metric')); + compress_chunk +------------------------------------------ + _timescaledb_internal._hyper_23_17_chunk +(1 row) + +-- column does not exist the first time +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" VARCHAR ; +-- column already exists the second time +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" VARCHAR ; +NOTICE: column "medium" of relation "metric" already exists, skipping +-- also add one without IF NOT EXISTS +ALTER TABLE metric ADD COLUMN "medium_1" VARCHAR ; +ALTER TABLE metric ADD COLUMN "medium_1" VARCHAR ; +ERROR: column "medium_1" of relation "metric" already exists diff --git a/tsl/test/expected/dist_compression.out b/tsl/test/expected/dist_compression.out index bf6edd0276a..4139c9777b2 100644 --- a/tsl/test/expected/dist_compression.out +++ b/tsl/test/expected/dist_compression.out @@ -1388,3 +1388,87 @@ ORDER BY 1; c2 (1 row) +-- test ADD COLUMN IF NOT EXISTS on a distributed hypertable +CREATE TABLE metric (time TIMESTAMPTZ NOT NULL, val FLOAT8 NOT NULL, dev_id INT4 NOT NULL); + +SELECT create_distributed_hypertable('metric', 'time'); + create_distributed_hypertable +------------------------------- + (10,public,metric,t) +(1 row) + +ALTER TABLE metric SET ( +timescaledb.compress, +timescaledb.compress_segmentby = 'dev_id', +timescaledb.compress_orderby = 'time DESC' +); + +INSERT INTO metric(time, val, dev_id) +SELECT s.*, 3.14+1, 1 +FROM generate_series('2021-07-01 00:00:00'::timestamp, + '2021-08-17 00:02:00'::timestamp, '30 s'::interval) s; + +SELECT compress_chunk(show_chunks('metric')); + compress_chunk +----------------------------------------------- + _timescaledb_internal._dist_hyper_10_36_chunk + _timescaledb_internal._dist_hyper_10_37_chunk + _timescaledb_internal._dist_hyper_10_38_chunk + _timescaledb_internal._dist_hyper_10_39_chunk + _timescaledb_internal._dist_hyper_10_40_chunk + _timescaledb_internal._dist_hyper_10_41_chunk + _timescaledb_internal._dist_hyper_10_42_chunk +(7 rows) + +-- make sure we have chunks on all data nodes +select * from timescaledb_information.chunks where hypertable_name like 'metric'; + hypertable_schema | hypertable_name | chunk_schema | chunk_name | primary_dimension | primary_dimension_type | range_start | range_end | range_start_integer | range_end_integer | is_compressed | chunk_tablespace | data_nodes +-------------------+-----------------+-----------------------+-------------------------+-------------------+--------------------------+------------------------------+------------------------------+---------------------+-------------------+---------------+------------------+------------------------- + public | metric | _timescaledb_internal | _dist_hyper_10_36_chunk | time | timestamp with time zone | Wed Jun 30 17:00:00 2021 PDT | Wed Jul 07 17:00:00 2021 PDT | | | t | | {db_dist_compression_2} + public | metric | _timescaledb_internal | _dist_hyper_10_37_chunk | time | timestamp with time zone | Wed Jul 07 17:00:00 2021 PDT | Wed Jul 14 17:00:00 2021 PDT | | | t | | {db_dist_compression_3} + public | metric | _timescaledb_internal | _dist_hyper_10_38_chunk | time | timestamp with time zone | Wed Jul 14 17:00:00 2021 PDT | Wed Jul 21 17:00:00 2021 PDT | | | t | | {db_dist_compression_1} + public | metric | _timescaledb_internal | _dist_hyper_10_39_chunk | time | timestamp with time zone | Wed Jul 21 17:00:00 2021 PDT | Wed Jul 28 17:00:00 2021 PDT | | | t | | {db_dist_compression_2} + public | metric | _timescaledb_internal | _dist_hyper_10_40_chunk | time | timestamp with time zone | Wed Jul 28 17:00:00 2021 PDT | Wed Aug 04 17:00:00 2021 PDT | | | t | | {db_dist_compression_3} + public | metric | _timescaledb_internal | _dist_hyper_10_41_chunk | time | timestamp with time zone | Wed Aug 04 17:00:00 2021 PDT | Wed Aug 11 17:00:00 2021 PDT | | | t | | {db_dist_compression_1} + public | metric | _timescaledb_internal | _dist_hyper_10_42_chunk | time | timestamp with time zone | Wed Aug 11 17:00:00 2021 PDT | Wed Aug 18 17:00:00 2021 PDT | | | t | | {db_dist_compression_2} +(7 rows) + +-- perform all combinations +-- [IF NOT EXISTS] - [] +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" varchar; +-- [IF NOT EXISTS] - ["medium"] +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" varchar; +NOTICE: column "medium" of relation "metric" already exists, skipping +-- [] - [] +ALTER TABLE metric ADD COLUMN "medium_1" varchar; +-- [] - ["medium_1"] +\set ON_ERROR_STOP 0 +ALTER TABLE metric ADD COLUMN "medium_1" varchar; +ERROR: column "medium_1" of relation "metric" already exists + +SELECT * FROM metric limit 5; + time | val | dev_id | medium | medium_1 +------------------------------+------+--------+--------+---------- + Wed Jul 21 16:59:30 2021 PDT | 4.14 | 1 | | + Wed Jul 21 16:59:00 2021 PDT | 4.14 | 1 | | + Wed Jul 21 16:58:30 2021 PDT | 4.14 | 1 | | + Wed Jul 21 16:58:00 2021 PDT | 4.14 | 1 | | + Wed Jul 21 16:57:30 2021 PDT | 4.14 | 1 | | +(5 rows) + +SELECT * FROM metric where medium is not null; + time | val | dev_id | medium | medium_1 +------+-----+--------+--------+---------- +(0 rows) + +-- INSERTs operate normally on the added column +INSERT INTO metric (time, val, dev_id, medium) +SELECT s.*, 3.14+1, 1, 'medium_value_text' +FROM generate_series('2021-08-18 00:00:00'::timestamp, + '2021-08-19 00:02:00'::timestamp, '30 s'::interval) s; +SELECT * FROM metric where medium is not null ORDER BY time LIMIT 1; + time | val | dev_id | medium | medium_1 +------------------------------+------+--------+-------------------+---------- + Wed Aug 18 00:00:00 2021 PDT | 4.14 | 1 | medium_value_text | +(1 row) + diff --git a/tsl/test/sql/compression_errors.sql b/tsl/test/sql/compression_errors.sql index 76b791ca8b1..6c179312d2a 100644 --- a/tsl/test/sql/compression_errors.sql +++ b/tsl/test/sql/compression_errors.sql @@ -282,3 +282,25 @@ SELECT config FROM _timescaledb_config.bgw_job WHERE id = :compressjob_id; --should fail CALL run_job(:compressjob_id); + +-- test ADD COLUMN IF NOT EXISTS +CREATE TABLE metric (time TIMESTAMPTZ NOT NULL, val FLOAT8 NOT NULL, dev_id INT4 NOT NULL); +SELECT create_hypertable('metric', 'time', 'dev_id', 10); +ALTER TABLE metric SET ( +timescaledb.compress, +timescaledb.compress_segmentby = 'dev_id', +timescaledb.compress_orderby = 'time DESC' +); + +INSERT INTO metric(time, val, dev_id) +SELECT s.*, 3.14+1, 1 +FROM generate_series('2021-08-17 00:00:00'::timestamp, + '2021-08-17 00:02:00'::timestamp, '1 s'::interval) s; +SELECT compress_chunk(show_chunks('metric')); +-- column does not exist the first time +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" VARCHAR ; +-- column already exists the second time +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" VARCHAR ; +-- also add one without IF NOT EXISTS +ALTER TABLE metric ADD COLUMN "medium_1" VARCHAR ; +ALTER TABLE metric ADD COLUMN "medium_1" VARCHAR ; \ No newline at end of file diff --git a/tsl/test/sql/dist_compression.sql b/tsl/test/sql/dist_compression.sql index 21b722586d0..fe9fba3cdd2 100644 --- a/tsl/test/sql/dist_compression.sql +++ b/tsl/test/sql/dist_compression.sql @@ -610,3 +610,42 @@ INNER JOIN _timescaledb_catalog.hypertable ht WHERE attname NOT IN ('time','device','o1','o2') ORDER BY 1; +-- test ADD COLUMN IF NOT EXISTS on a distributed hypertable +CREATE TABLE metric (time TIMESTAMPTZ NOT NULL, val FLOAT8 NOT NULL, dev_id INT4 NOT NULL); + +SELECT create_distributed_hypertable('metric', 'time'); +ALTER TABLE metric SET ( +timescaledb.compress, +timescaledb.compress_segmentby = 'dev_id', +timescaledb.compress_orderby = 'time DESC' +); + +INSERT INTO metric(time, val, dev_id) +SELECT s.*, 3.14+1, 1 +FROM generate_series('2021-07-01 00:00:00'::timestamp, + '2021-08-17 00:02:00'::timestamp, '30 s'::interval) s; + +SELECT compress_chunk(show_chunks('metric')); +-- make sure we have chunks on all data nodes +select * from timescaledb_information.chunks where hypertable_name like 'metric'; +-- perform all combinations +-- [IF NOT EXISTS] - [] +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" varchar; +-- [IF NOT EXISTS] - ["medium"] +ALTER TABLE metric ADD COLUMN IF NOT EXISTS "medium" varchar; +-- [] - [] +ALTER TABLE metric ADD COLUMN "medium_1" varchar; +-- [] - ["medium_1"] +\set ON_ERROR_STOP 0 +ALTER TABLE metric ADD COLUMN "medium_1" varchar; + +SELECT * FROM metric limit 5; +SELECT * FROM metric where medium is not null; + +-- INSERTs operate normally on the added column +INSERT INTO metric (time, val, dev_id, medium) +SELECT s.*, 3.14+1, 1, 'medium_value_text' +FROM generate_series('2021-08-18 00:00:00'::timestamp, + '2021-08-19 00:02:00'::timestamp, '30 s'::interval) s; + +SELECT * FROM metric where medium is not null ORDER BY time LIMIT 1; \ No newline at end of file