1
0
mirror of https://github.com/timescale/timescaledb.git synced 2025-05-17 02:53:51 +08:00

Add support for most triggers on hypertables

This adds support for all types of triggers on a hypertable except
INSERT AFTER. UPDATE and DELETE ROW triggers are automatically copied from
a hypertable onto the chunks. Therefore, any trigger defined on the
parent hypertable will apply to any row in any of the chunks as well.
STATEMENT level triggers and iNSERT triggers need not be copied in this
way.
This commit is contained in:
Matvey Arye 2017-07-10 23:52:25 -04:00 committed by Matvey Arye
parent e0eeeb9bdb
commit 83c75fd154
16 changed files with 673 additions and 79 deletions

@ -299,3 +299,59 @@ BEGIN
RETURN chunk_row;
END
$BODY$;
-- Trigger for when chunk rows are changed.
-- On Insert: create chunk table, add indexes, add triggers.
-- On Delete: drop table
CREATE OR REPLACE FUNCTION _timescaledb_internal.on_change_chunk()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$BODY$
DECLARE
kind pg_class.relkind%type;
hypertable_row _timescaledb_catalog.hypertable;
BEGIN
IF TG_OP = 'INSERT' THEN
PERFORM _timescaledb_internal.chunk_create_table(NEW.id);
PERFORM _timescaledb_internal.create_chunk_index_row(NEW.schema_name, NEW.table_name,
hi.main_schema_name, hi.main_index_name, hi.definition)
FROM _timescaledb_catalog.hypertable_index hi
WHERE hi.hypertable_id = NEW.hypertable_id;
SELECT * INTO STRICT hypertable_row FROM _timescaledb_catalog.hypertable WHERE id = NEW.hypertable_id;
PERFORM _timescaledb_internal.create_chunk_trigger(NEW.id, tgname,
_timescaledb_internal.get_general_trigger_definition(oid))
FROM pg_trigger
WHERE tgrelid = format('%I.%I', hypertable_row.schema_name, hypertable_row.table_name)::regclass
AND _timescaledb_internal.need_chunk_trigger(NEW.hypertable_id, oid);
RETURN NEW;
ELSIF TG_OP = 'DELETE' THEN
-- when deleting the chunk row from the metadata table,
-- also DROP the actual chunk table that holds data.
-- Note that the table could already be deleted in case this
-- trigger fires as a result of a DROP TABLE on the hypertable
-- that this chunk belongs to.
EXECUTE format(
$$
SELECT c.relkind FROM pg_class c WHERE relname = '%I' AND relnamespace = '%I'::regnamespace
$$, OLD.table_name, OLD.schema_name
) INTO kind;
IF kind IS NULL THEN
RETURN OLD;
END IF;
EXECUTE format(
$$
DROP TABLE %I.%I
$$, OLD.schema_name, OLD.table_name
);
RETURN OLD;
END IF;
PERFORM _timescaledb_internal.on_trigger_error(TG_OP, TG_TABLE_SCHEMA, TG_TABLE_NAME);
END
$BODY$;

84
sql/chunk_trigger.sql Normal file

@ -0,0 +1,84 @@
-- Convert a general trigger definition to a create trigger sql command for a
-- particular table and trigger name.
-- static
CREATE OR REPLACE FUNCTION _timescaledb_internal.get_trigger_definition_for_table(
chunk_id INTEGER,
general_definition TEXT
)
RETURNS TEXT LANGUAGE PLPGSQL AS
$BODY$
DECLARE
chunk_row _timescaledb_catalog.chunk;
sql_code TEXT;
BEGIN
SELECT * INTO STRICT chunk_row FROM _timescaledb_catalog.chunk WHERE id = chunk_id;
sql_code := replace(general_definition, '/*TABLE_NAME*/', format('%I.%I', chunk_row.schema_name, chunk_row.table_name));
RETURN sql_code;
END
$BODY$;
-- Creates a chunk_trigger_row.
CREATE OR REPLACE FUNCTION _timescaledb_internal.create_chunk_trigger(
chunk_id INTEGER,
trigger_name NAME,
def TEXT
)
RETURNS VOID LANGUAGE PLPGSQL AS
$BODY$
DECLARE
sql_code TEXT;
BEGIN
sql_code := _timescaledb_internal.get_trigger_definition_for_table(chunk_id, def);
EXECUTE sql_code;
END
$BODY$;
CREATE OR REPLACE FUNCTION _timescaledb_internal.drop_chunk_trigger(
chunk_id INTEGER,
trigger_name NAME
)
RETURNS VOID LANGUAGE PLPGSQL AS
$BODY$
DECLARE
chunk_row _timescaledb_catalog.chunk;
BEGIN
SELECT * INTO STRICT chunk_row FROM _timescaledb_catalog.chunk WHERE id = chunk_id;
EXECUTE format($$ DROP TRIGGER IF EXISTS %I ON %I.%I $$, trigger_name, chunk_row.schema_name, chunk_row.table_name);
END
$BODY$
SET client_min_messages = WARNING;
-- Creates a trigger on all chunk for a hypertable.
-- static
CREATE OR REPLACE FUNCTION _timescaledb_internal.create_trigger_on_all_chunks(
hypertable_id INTEGER,
trigger_name NAME,
definition TEXT
)
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
$BODY$
DECLARE
BEGIN
PERFORM _timescaledb_internal.create_chunk_trigger(c.id, trigger_name, definition)
FROM _timescaledb_catalog.chunk c
WHERE c.hypertable_id = create_trigger_on_all_chunks.hypertable_id;
END
$BODY$;
-- Drops trigger on all chunks for a hypertable.
-- static
CREATE OR REPLACE FUNCTION _timescaledb_internal.drop_trigger_on_all_chunks(
hypertable_id INTEGER,
trigger_name NAME
)
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
$BODY$
BEGIN
PERFORM _timescaledb_internal.drop_chunk_trigger(c.id, trigger_name)
FROM _timescaledb_catalog.chunk c
WHERE c.hypertable_id = drop_trigger_on_all_chunks.hypertable_id;
END
$BODY$;

@ -1,47 +0,0 @@
-- Trigger for when chunk rows are changed.
-- On Insert: create chunk table, add indexes, add constraints.
-- On Update: change constraints.
-- On Delete: drop table
CREATE OR REPLACE FUNCTION _timescaledb_internal.on_change_chunk()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$BODY$
DECLARE
kind pg_class.relkind%type;
BEGIN
IF TG_OP = 'INSERT' THEN
PERFORM _timescaledb_internal.chunk_create_table(NEW.id);
PERFORM _timescaledb_internal.create_chunk_index_row(NEW.schema_name, NEW.table_name,
hi.main_schema_name, hi.main_index_name, hi.definition)
FROM _timescaledb_catalog.hypertable_index hi
WHERE hi.hypertable_id = NEW.hypertable_id;
RETURN NEW;
ELSIF TG_OP = 'DELETE' THEN
-- when deleting the chunk row from the metadata table,
-- also DROP the actual chunk table that holds data.
-- Note that the table could already be deleted in case this
-- trigger fires as a result of a DROP TABLE on the hypertable
-- that this chunk belongs to.
EXECUTE format(
$$
SELECT c.relkind FROM pg_class c WHERE relname = '%I' AND relnamespace = '%I'::regnamespace
$$, OLD.table_name, OLD.schema_name
) INTO kind;
IF kind IS NULL THEN
RETURN OLD;
END IF;
EXECUTE format(
$$
DROP TABLE %I.%I
$$, OLD.schema_name, OLD.table_name
);
RETURN OLD;
END IF;
PERFORM _timescaledb_internal.on_trigger_error(TG_OP, TG_TABLE_SCHEMA, TG_TABLE_NAME);
END
$BODY$;

@ -120,6 +120,15 @@ BEGIN
)
WHERE indrelid = main_table;
PERFORM 1
FROM pg_trigger,
LATERAL _timescaledb_internal.add_trigger(
hypertable_row.id,
oid
)
WHERE tgrelid = main_table
AND _timescaledb_internal.need_chunk_trigger(hypertable_row.id, oid);
IF create_default_indexes THEN
PERFORM _timescaledb_internal.create_default_indexes(hypertable_row, main_table, partitioning_column);
END IF;

@ -173,6 +173,58 @@ INSERT INTO _timescaledb_catalog.hypertable_index (hypertable_id, main_schema_na
VALUES (hypertable_id, main_schema_name, main_index_name, definition);
$BODY$;
-- Add a trigger to a hypertable
CREATE OR REPLACE FUNCTION _timescaledb_internal.need_chunk_trigger(
hypertable_id INTEGER,
trigger_oid OID
)
RETURNS BOOLEAN LANGUAGE PLPGSQL VOLATILE AS
$BODY$
DECLARE
trigger_row record;
BEGIN
SELECT * INTO STRICT trigger_row FROM pg_trigger WHERE OID = trigger_oid;
IF trigger_row.tgname = ANY(_timescaledb_internal.timescale_trigger_names()) THEN
RETURN FALSE;
END IF;
IF (trigger_row.tgtype & (1 << 2) != 0) THEN
--is INSERT trigger
IF (trigger_row.tgtype & (1 << 3) != 0) OR (trigger_row.tgtype & (1 << 4) != 0) THEN
RAISE 'Combining INSERT triggers with UPDATE or DELETE triggers is not supported.'
USING HINT = 'Please define separate triggers for each operation';
END IF;
IF (trigger_row.tgtype & ((1 << 1) | (1 << 6)) = 0) THEN
RAISE 'AFTER trigger on INSERT is not supported: %.', trigger_row.tgname;
END IF;
ELSE
IF (trigger_row.tgtype & (1 << 0) != 0) THEN
RETURN TRUE;
END IF;
END IF;
RETURN FALSE;
END
$BODY$;
-- Add a trigger to a hypertable
CREATE OR REPLACE FUNCTION _timescaledb_internal.add_trigger(
hypertable_id INTEGER,
trigger_oid OID
)
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
$BODY$
DECLARE
trigger_row record;
BEGIN
IF _timescaledb_internal.need_chunk_trigger(hypertable_id, trigger_oid) THEN
SELECT * INTO STRICT trigger_row FROM pg_trigger WHERE OID = trigger_oid;
PERFORM _timescaledb_internal.create_trigger_on_all_chunks(hypertable_id, trigger_row.tgname,
_timescaledb_internal.get_general_trigger_definition(trigger_oid));
END IF;
END
$BODY$;
-- Drops the index for a hypertable
CREATE OR REPLACE FUNCTION _timescaledb_internal.drop_index(
main_schema_name NAME,
@ -309,6 +361,43 @@ BEGIN
END
$BODY$;
-- Create the "general definition" of a trigger. The general definition
-- is the corresponding create trigger command with the placeholders /*TABLE_NAME*/
CREATE OR REPLACE FUNCTION _timescaledb_internal.get_general_trigger_definition(
trigger_oid REGCLASS
)
RETURNS text
LANGUAGE plpgsql VOLATILE AS
$BODY$
DECLARE
def TEXT;
c INTEGER;
trigger_row RECORD;
BEGIN
-- Get trigger definition
def := pg_get_triggerdef(trigger_oid);
IF def IS NULL THEN
RAISE EXCEPTION 'Cannot process trigger with no definition: %', trigger_oid::TEXT;
END IF;
SELECT * INTO STRICT trigger_row FROM pg_trigger WHERE oid = trigger_oid;
SELECT count(*) INTO c
FROM regexp_matches(def, 'ON '|| trigger_row.tgrelid::regclass::TEXT, 'g');
IF c <> 1 THEN
RAISE EXCEPTION 'Cannot process trigger with definition(no table name match: %): %', trigger_row.tgrelid::regclass::TEXT, def
USING ERRCODE = 'IO103';
END IF;
def := replace(def, 'ON '|| trigger_row.tgrelid::regclass::TEXT, 'ON /*TABLE_NAME*/');
RETURN def;
END
$BODY$;
-- Creates the default indexes on a hypertable.
CREATE OR REPLACE FUNCTION _timescaledb_internal.create_default_indexes(
hypertable_row _timescaledb_catalog.hypertable,
@ -359,7 +448,6 @@ BEGIN
END
$BODY$;
CREATE OR REPLACE FUNCTION _timescaledb_internal.rename_hypertable(
old_schema NAME,
old_table_name NAME,
@ -386,3 +474,9 @@ BEGIN
table_name = old_table_name;
END
$BODY$;
CREATE OR REPLACE FUNCTION _timescaledb_internal.timescale_trigger_names()
RETURNS text[] LANGUAGE SQL IMMUTABLE AS
$BODY$
SELECT array['_timescaledb_main_insert_trigger', '_timescaledb_main_after_insert_trigger'];
$BODY$;

@ -56,26 +56,55 @@ $BODY$;
-- Handles ddl create trigger commands on hypertables
CREATE OR REPLACE FUNCTION _timescaledb_internal.ddl_process_create_trigger()
RETURNS event_trigger LANGUAGE plpgsql AS
RETURNS event_trigger LANGUAGE plpgsql
SECURITY DEFINER SET search_path = ''
AS
$BODY$
DECLARE
info record;
table_oid regclass;
trigger_name TEXT;
info record;
table_oid regclass;
index_oid OID;
trigger_name TEXT;
hypertable_row _timescaledb_catalog.hypertable;
BEGIN
--NOTE: pg_event_trigger_ddl_commands prevents this SECURITY DEFINER function from being called outside trigger.
FOR info IN SELECT * FROM pg_event_trigger_ddl_commands()
LOOP
SELECT tgrelid, tgname INTO STRICT table_oid, trigger_name
SELECT OID, tgrelid, tgname INTO STRICT index_oid, table_oid, trigger_name
FROM pg_catalog.pg_trigger
WHERE oid = info.objid;
IF _timescaledb_internal.is_main_table(table_oid)
AND trigger_name != '_timescaledb_main_insert_trigger'
AND trigger_name != '_timescaledb_main_after_insert_trigger'
AND trigger_name != '_timescaledb_modify_trigger'
AND trigger_name <> ALL(_timescaledb_internal.timescale_trigger_names())
THEN
RAISE EXCEPTION 'CREATE TRIGGER not supported on hypertable %', table_oid
USING ERRCODE = 'IO101';
hypertable_row := _timescaledb_internal.hypertable_from_main_table(table_oid);
PERFORM _timescaledb_internal.add_trigger(hypertable_row.id, index_oid);
END IF;
END LOOP;
END
$BODY$;
-- Handles ddl drop index commands on hypertables
CREATE OR REPLACE FUNCTION _timescaledb_internal.ddl_process_drop_trigger()
RETURNS event_trigger LANGUAGE plpgsql
SECURITY DEFINER SET search_path = ''
AS
$BODY$
DECLARE
info record;
hypertable_row _timescaledb_catalog.hypertable;
BEGIN
--NOTE: pg_event_trigger_ddl_commands prevents this SECURITY DEFINER function from being called outside trigger.
FOR info IN SELECT * FROM pg_event_trigger_dropped_objects()
LOOP
IF info.classid = 'pg_trigger'::regclass THEN
SELECT * INTO hypertable_row
FROM _timescaledb_catalog.hypertable
WHERE schema_name = info.address_names[1] AND table_name = info.address_names[2];
IF hypertable_row IS NOT NULL THEN
PERFORM _timescaledb_internal.drop_trigger_on_all_chunks(hypertable_row.id, info.address_names[3]);
END IF;
END IF;
END LOOP;
END

@ -3,14 +3,13 @@ sql/ddl_internal.sql
sql/util_time.sql
sql/util_internal_table_ddl.sql
sql/chunk.sql
sql/chunk_trigger.sql
sql/hypertable_triggers.sql
sql/hypertable_index_triggers.sql
sql/partitioning.sql
sql/schema_info.sql
sql/chunk_index.sql
sql/chunk_triggers.sql
sql/chunk_index_triggers.sql
sql/chunk_triggers.sql
sql/setup_main.sql
sql/ddl_api.sql
sql/ddl_triggers.sql

@ -34,7 +34,6 @@ BEGIN
AFTER INSERT OR UPDATE OR DELETE ON _timescaledb_catalog.hypertable_index
FOR EACH ROW EXECUTE PROCEDURE _timescaledb_internal.on_change_hypertable_index();
-- No support for TRUNCATE currently, so have a trigger to prevent it on
-- all meta tables.
FOREACH table_name IN ARRAY ARRAY ['hypertable', 'hypertable_index',
@ -64,6 +63,10 @@ BEGIN
WHEN tag IN ('create trigger')
EXECUTE PROCEDURE _timescaledb_internal.ddl_process_create_trigger();
CREATE EVENT TRIGGER ddl_drop_trigger
ON sql_drop
EXECUTE PROCEDURE _timescaledb_internal.ddl_process_drop_trigger();
CREATE EVENT TRIGGER ddl_alter_table ON ddl_command_end
WHEN tag IN ('alter table')
EXECUTE PROCEDURE _timescaledb_internal.ddl_process_alter_table();
@ -77,6 +80,7 @@ BEGIN
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_alter_index;
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_drop_index;
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_create_trigger;
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_drop_trigger;
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_alter_table;
ALTER EXTENSION timescaledb ADD EVENT TRIGGER ddl_check_drop_command;
END IF;

@ -134,8 +134,15 @@ insert_chunk_state_new(Chunk *chunk)
ExecOpenIndices(resultRelInfo, false);
if (resultRelInfo->ri_TrigDesc != NULL)
elog(ERROR, "triggers on chunk tables not supported");
{
if (resultRelInfo->ri_TrigDesc->trig_insert_instead_row ||
resultRelInfo->ri_TrigDesc->trig_insert_after_row ||
resultRelInfo->ri_TrigDesc->trig_insert_before_row ||
resultRelInfo->ri_TrigDesc->trig_insert_after_statement ||
resultRelInfo->ri_TrigDesc->trig_insert_before_statement
)
elog(ERROR, "Insert trigger on chunk tables not supported");
}
rel_state = insert_chunk_state_rel_new(rel, resultRelInfo, range_table);
rel_state_list = lappend(rel_state_list, rel_state);

@ -443,14 +443,13 @@ $BODY$
BEGIN
END
$BODY$;
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
--expect error cases
\set ON_ERROR_STOP 0
ALTER TABLE PUBLIC."Hypertable_1" ALTER COLUMN sensor_2_renamed SET DATA TYPE int;
ALTER INDEX "ind_humidity" RENAME TO "ind_humdity2";
psql:include/ddl_ops_2.sql:24: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
psql:include/ddl_ops_2.sql:26: ERROR: CREATE TRIGGER not supported on hypertable "Hypertable_1"
psql:include/ddl_ops_2.sql:27: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
\set ON_ERROR_STOP 1
--create column with same name as previously renamed one
ALTER TABLE PUBLIC."Hypertable_1" ADD COLUMN sensor_3 BIGINT NOT NULL DEFAULT 131;

@ -424,14 +424,13 @@ $BODY$
BEGIN
END
$BODY$;
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
--expect error cases
\set ON_ERROR_STOP 0
ALTER TABLE PUBLIC."Hypertable_1" ALTER COLUMN sensor_2_renamed SET DATA TYPE int;
ALTER INDEX "ind_humidity" RENAME TO "ind_humdity2";
psql:include/ddl_ops_2.sql:24: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
psql:include/ddl_ops_2.sql:26: ERROR: CREATE TRIGGER not supported on hypertable "Hypertable_1"
psql:include/ddl_ops_2.sql:27: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
\set ON_ERROR_STOP 1
--create column with same name as previously renamed one
ALTER TABLE PUBLIC."Hypertable_1" ADD COLUMN sensor_3 BIGINT NOT NULL DEFAULT 131;
@ -460,6 +459,7 @@ Indexes:
Triggers:
_timescaledb_main_after_insert_trigger AFTER INSERT ON "Hypertable_1" FOR EACH STATEMENT EXECUTE PROCEDURE _timescaledb_internal.main_table_after_insert_trigger()
_timescaledb_main_insert_trigger BEFORE INSERT ON "Hypertable_1" FOR EACH ROW EXECUTE PROCEDURE _timescaledb_internal.main_table_insert_trigger()
test_trigger BEFORE DELETE OR UPDATE ON "Hypertable_1" FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func()
Child tables: _timescaledb_internal._hyper_1_1_chunk
SELECT * FROM PUBLIC."Hypertable_1";

@ -363,14 +363,13 @@ $BODY$
BEGIN
END
$BODY$;
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
--expect error cases
\set ON_ERROR_STOP 0
ALTER TABLE PUBLIC."Hypertable_1" ALTER COLUMN sensor_2_renamed SET DATA TYPE int;
ALTER INDEX "ind_humidity" RENAME TO "ind_humdity2";
psql:include/ddl_ops_2.sql:24: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
psql:include/ddl_ops_2.sql:26: ERROR: CREATE TRIGGER not supported on hypertable "Hypertable_1"
psql:include/ddl_ops_2.sql:27: ERROR: ALTER INDEX not supported on hypertable public."Hypertable_1"
\set ON_ERROR_STOP 1
--create column with same name as previously renamed one
ALTER TABLE PUBLIC."Hypertable_1" ADD COLUMN sensor_3 BIGINT NOT NULL DEFAULT 131;
@ -399,6 +398,7 @@ Indexes:
Triggers:
_timescaledb_main_after_insert_trigger AFTER INSERT ON "Hypertable_1" FOR EACH STATEMENT EXECUTE PROCEDURE _timescaledb_internal.main_table_after_insert_trigger()
_timescaledb_main_insert_trigger BEFORE INSERT ON "Hypertable_1" FOR EACH ROW EXECUTE PROCEDURE _timescaledb_internal.main_table_insert_trigger()
test_trigger BEFORE DELETE OR UPDATE ON "Hypertable_1" FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func()
Child tables: _timescaledb_internal._hyper_1_1_chunk
\d+ _timescaledb_internal._hyper_1_1_chunk

@ -42,7 +42,7 @@ SELECT count(*)
AND refobjid = (SELECT oid FROM pg_extension WHERE extname = 'timescaledb');
count
-------
115
126
(1 row)
\c postgres
@ -66,7 +66,7 @@ SELECT count(*)
AND refobjid = (SELECT oid FROM pg_extension WHERE extname = 'timescaledb');
count
-------
115
126
(1 row)
\c single

181
test/expected/triggers.out Normal file

@ -0,0 +1,181 @@
\o /dev/null
\ir include/create_single_db.sql
SET client_min_messages = WARNING;
DROP DATABASE IF EXISTS single;
SET client_min_messages = NOTICE;
CREATE DATABASE single;
\c single
CREATE EXTENSION IF NOT EXISTS timescaledb;
\o
CREATE TABLE hyper (
time BIGINT NOT NULL,
device_id TEXT NOT NULL,
sensor_1 NUMERIC NULL DEFAULT 1
);
CREATE OR REPLACE FUNCTION test_trigger()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$BODY$
DECLARE
cnt INTEGER;
BEGIN
SELECT count(*) INTO cnt FROM hyper;
RAISE WARNING 'FIRING trigger when: % level: % op: % cnt: %', tg_when, tg_level, tg_op, cnt;
IF TG_OP = 'DELETE' THEN
RETURN OLD;
END IF;
RETURN NEW;
END
$BODY$;
CREATE TRIGGER _0_test_trigger
BEFORE INSERT OR UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
ERROR: Combining INSERT triggers with UPDATE or DELETE triggers is not supported.
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger
AFTER INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
ERROR: AFTER trigger on INSERT is not supported: _0_test_trigger.
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger
AFTER INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
ERROR: AFTER trigger on INSERT is not supported: _0_test_trigger.
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger_insert
BEFORE INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_insert_s_before
BEFORE INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update
BEFORE UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete
BEFORE delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_before
BEFORE UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_before
BEFORE DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_after
AFTER UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_after
AFTER delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_after
AFTER UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_after
AFTER DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
SELECT * FROM create_hypertable('hyper', 'time', chunk_time_interval => 10);
create_hypertable
-------------------
(1 row)
--test triggers before create_hypertable
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: INSERT cnt: 0
WARNING: FIRING trigger when: BEFORE level: ROW op: INSERT cnt: 0
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: INSERT cnt: 1
WARNING: FIRING trigger when: BEFORE level: ROW op: INSERT cnt: 1
UPDATE hyper SET sensor_1 = 2;
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: UPDATE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: STATEMENT op: UPDATE cnt: 2
DELETE FROM hyper;
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: DELETE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: DELETE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: DELETE cnt: 1
WARNING: FIRING trigger when: AFTER level: ROW op: DELETE cnt: 0
WARNING: FIRING trigger when: AFTER level: ROW op: DELETE cnt: 0
WARNING: FIRING trigger when: AFTER level: STATEMENT op: DELETE cnt: 0
--test drop trigger
DROP TRIGGER _0_test_trigger_insert ON hyper;
DROP TRIGGER _0_test_trigger_insert_s_before ON hyper;
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
DROP TRIGGER _0_test_trigger_update ON hyper;
DROP TRIGGER _0_test_trigger_update_s_before ON hyper;
DROP TRIGGER _0_test_trigger_update_after ON hyper;
DROP TRIGGER _0_test_trigger_update_s_after ON hyper;
UPDATE hyper SET sensor_1 = 2;
DROP TRIGGER _0_test_trigger_delete ON hyper;
DROP TRIGGER _0_test_trigger_delete_s_before ON hyper;
DROP TRIGGER _0_test_trigger_delete_after ON hyper;
DROP TRIGGER _0_test_trigger_delete_s_after ON hyper;
DELETE FROM hyper;
--test create trigger on hypertable
CREATE TRIGGER _0_test_trigger_insert
BEFORE INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_insert_s_before
BEFORE INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update
BEFORE UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete
BEFORE delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_before
BEFORE UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_before
BEFORE DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_after
AFTER UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_after
AFTER delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_after
AFTER UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_after
AFTER DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: INSERT cnt: 0
WARNING: FIRING trigger when: BEFORE level: ROW op: INSERT cnt: 0
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: INSERT cnt: 1
WARNING: FIRING trigger when: BEFORE level: ROW op: INSERT cnt: 1
UPDATE hyper SET sensor_1 = 2;
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: UPDATE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: ROW op: UPDATE cnt: 2
WARNING: FIRING trigger when: AFTER level: STATEMENT op: UPDATE cnt: 2
DELETE FROM hyper;
WARNING: FIRING trigger when: BEFORE level: STATEMENT op: DELETE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: DELETE cnt: 2
WARNING: FIRING trigger when: BEFORE level: ROW op: DELETE cnt: 1
WARNING: FIRING trigger when: AFTER level: ROW op: DELETE cnt: 0
WARNING: FIRING trigger when: AFTER level: ROW op: DELETE cnt: 0
WARNING: FIRING trigger when: AFTER level: STATEMENT op: DELETE cnt: 0

@ -18,12 +18,13 @@ BEGIN
END
$BODY$;
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
--expect error cases
\set ON_ERROR_STOP 0
ALTER TABLE PUBLIC."Hypertable_1" ALTER COLUMN sensor_2_renamed SET DATA TYPE int;
ALTER INDEX "ind_humidity" RENAME TO "ind_humdity2";
CREATE TRIGGER test_trigger BEFORE UPDATE OR DELETE ON PUBLIC."Hypertable_1"
FOR EACH STATEMENT EXECUTE PROCEDURE empty_trigger_func();
\set ON_ERROR_STOP 1
--create column with same name as previously renamed one

178
test/sql/triggers.sql Normal file

@ -0,0 +1,178 @@
\o /dev/null
\ir include/create_single_db.sql
\o
CREATE TABLE hyper (
time BIGINT NOT NULL,
device_id TEXT NOT NULL,
sensor_1 NUMERIC NULL DEFAULT 1
);
CREATE OR REPLACE FUNCTION test_trigger()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$BODY$
DECLARE
cnt INTEGER;
BEGIN
SELECT count(*) INTO cnt FROM hyper;
RAISE WARNING 'FIRING trigger when: % level: % op: % cnt: %', tg_when, tg_level, tg_op, cnt;
IF TG_OP = 'DELETE' THEN
RETURN OLD;
END IF;
RETURN NEW;
END
$BODY$;
CREATE TRIGGER _0_test_trigger
BEFORE INSERT OR UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger
AFTER INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger
AFTER INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
\set ON_ERROR_STOP 0
SELECT * FROM create_hypertable('hyper', 'time');
\set ON_ERROR_STOP 1
DROP TRIGGER _0_test_trigger ON hyper;
CREATE TRIGGER _0_test_trigger_insert
BEFORE INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_insert_s_before
BEFORE INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update
BEFORE UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete
BEFORE delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_before
BEFORE UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_before
BEFORE DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_after
AFTER UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_after
AFTER delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_after
AFTER UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_after
AFTER DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
SELECT * FROM create_hypertable('hyper', 'time', chunk_time_interval => 10);
--test triggers before create_hypertable
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
UPDATE hyper SET sensor_1 = 2;
DELETE FROM hyper;
--test drop trigger
DROP TRIGGER _0_test_trigger_insert ON hyper;
DROP TRIGGER _0_test_trigger_insert_s_before ON hyper;
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
DROP TRIGGER _0_test_trigger_update ON hyper;
DROP TRIGGER _0_test_trigger_update_s_before ON hyper;
DROP TRIGGER _0_test_trigger_update_after ON hyper;
DROP TRIGGER _0_test_trigger_update_s_after ON hyper;
UPDATE hyper SET sensor_1 = 2;
DROP TRIGGER _0_test_trigger_delete ON hyper;
DROP TRIGGER _0_test_trigger_delete_s_before ON hyper;
DROP TRIGGER _0_test_trigger_delete_after ON hyper;
DROP TRIGGER _0_test_trigger_delete_s_after ON hyper;
DELETE FROM hyper;
--test create trigger on hypertable
CREATE TRIGGER _0_test_trigger_insert
BEFORE INSERT ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_insert_s_before
BEFORE INSERT ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update
BEFORE UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete
BEFORE delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_before
BEFORE UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_before
BEFORE DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_after
AFTER UPDATE ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_after
AFTER delete ON hyper
FOR EACH ROW EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_update_s_after
AFTER UPDATE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
CREATE TRIGGER _0_test_trigger_delete_s_after
AFTER DELETE ON hyper
FOR EACH STATEMENT EXECUTE PROCEDURE test_trigger();
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987600000000000, 'dev1', 1);
INSERT INTO hyper(time, device_id,sensor_1) VALUES
(1257987700000000000, 'dev2', 1);
UPDATE hyper SET sensor_1 = 2;
DELETE FROM hyper;