DROP TRIGGER
Description
DROP TRIGGER is used to delete a trigger.
Precautions
Only the trigger owner or a user granted the DROP ANY TRIGGER permission can run the DROP TRIGGER command. The system administrator has this permission by default.
Syntax
DROP TRIGGER [ IF EXISTS ] name ON table_name [ CASCADE | RESTRICT ];
Parameters
- IF EXISTS
Reports a notice instead of an error if the specified trigger does not exist.
- trigger_name
Specifies the name of the trigger to be deleted.
Value range: an existing trigger name
- table_name
Specifies the name of the table containing the trigger.
Value range: name of the table containing the trigger
- CASCADE | RESTRICT
- CASCADE: automatically deletes the objects that depend on the trigger.
- RESTRICT: refuses to delete the trigger if any objects depend on it. This is the default action.
Examples
-- Create a source table and a target table. gaussdb=# CREATE TABLE test_trigger_src_tbl(id1 INT, id2 INT, id3 INT); gaussdb=# CREATE TABLE test_trigger_des_tbl(id1 INT, id2 INT, id3 INT);
Use the INSERT trigger.
-- Create an INSERT trigger function. gaussdb=# CREATE OR REPLACE FUNCTION tri_insert_func() RETURNS TRIGGER AS $$ DECLARE BEGIN INSERT INTO test_trigger_des_tbl VALUES(NEW.id1, NEW.id2, NEW.id3); RETURN NEW; END $$ LANGUAGE plpgsql; -- Create an INSERT trigger. gaussdb=# CREATE TRIGGER insert_trigger BEFORE INSERT ON test_trigger_src_tbl FOR EACH ROW EXECUTE PROCEDURE tri_insert_func(); -- Execute the INSERT event and check the trigger results. gaussdb=# INSERT INTO test_trigger_src_tbl VALUES(100,200,300); gaussdb=# SELECT * FROM test_trigger_src_tbl; id1 | id2 | id3 -----+-----+----- 100 | 200 | 300 (1 row) gaussdb=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. id1 | id2 | id3 -----+-----+----- 100 | 200 | 300 (1 row)
Use anonymous blocks and the OR REPLACE syntax to create triggers.
-- Create an INSERT trigger using the anonymous block syntax. gaussdb=# CREATE TRIGGER insert_trigger_with_anonyblock BEFORE INSERT ON test_trigger_src_tbl FOR EACH ROW DECLARE BEGIN INSERT INTO test_trigger_des_tbl VALUES(NEW.id1, NEW.id2, NEW.id3); RETURN NEW; END; / -- Create an INSERT trigger using the OR REPLACE syntax. gaussdb=# CREATE OR REPLACE TRIGGER insert_trigger_with_anonyblock BEFORE INSERT ON test_trigger_src_tbl FOR EACH ROW DECLARE BEGIN INSERT INTO test_trigger_des_tbl VALUES(NEW.id1, NEW.id2, NEW.id3); RETURN NEW; END; / -- Drop the trigger. gaussdb=# DROP TRIGGER insert_trigger_with_anonyblock ON test_trigger_src_tbl; -- Drop the implicitly created function insert_trigger_with_anonyblock.
Use the UPDATE trigger.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 |
-- Create an UPDATE trigger function. gaussdb=# CREATE OR REPLACE FUNCTION tri_update_func() RETURNS TRIGGER AS $$ DECLARE BEGIN UPDATE test_trigger_des_tbl SET id3 = NEW.id3 WHERE id1=OLD.id1; RETURN OLD; END $$ LANGUAGE plpgsql; -- Create an UPDATE trigger. gaussdb=# CREATE TRIGGER update_trigger AFTER UPDATE ON test_trigger_src_tbl FOR EACH ROW EXECUTE PROCEDURE tri_update_func(); -- Execute the UPDATE event and check the trigger results. gaussdb=# UPDATE test_trigger_src_tbl SET id3=400 WHERE id1=100; gaussdb=# SELECT * FROM test_trigger_src_tbl; id1 | id2 | id3 -----+-----+----- 100 | 200 | 400 (1 row) gaussdb=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. id1 | id2 | id3 -----+-----+----- 100 | 200 | 400 (1 row) |
Use the DELETE trigger.
-- Create a DELETE trigger function. gaussdb=# CREATE OR REPLACE FUNCTION TRI_DELETE_FUNC() RETURNS TRIGGER AS $$ DECLARE BEGIN DELETE FROM test_trigger_des_tbl WHERE id1=OLD.id1; RETURN OLD; END $$ LANGUAGE plpgsql; -- Create a DELETE trigger. gaussdb=# CREATE TRIGGER delete_trigger BEFORE DELETE ON test_trigger_src_tbl FOR EACH ROW EXECUTE PROCEDURE tri_delete_func(); -- Execute the DELETE event and check the trigger results. gaussdb=# DELETE FROM test_trigger_src_tbl WHERE id1=100; gaussdb=# SELECT * FROM test_trigger_src_tbl; id1 | id2 | id3 -----+-----+----- (0 rows) gaussdb=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. id1 | id2 | id3 -----+-----+----- (0 rows)
Rename a trigger.
1 2 |
-- Rename a trigger. gaussdb=# ALTER TRIGGER delete_trigger ON test_trigger_src_tbl RENAME TO delete_trigger_renamed; |
Disable a trigger.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
-- Disable insert_trigger. gaussdb=# ALTER TABLE test_trigger_src_tbl DISABLE TRIGGER insert_trigger; gaussdb=# INSERT INTO test_trigger_src_tbl VALUES(100,200,300); gaussdb=# SELECT * FROM test_trigger_src_tbl; id1 | id2 | id3 -----+-----+----- 100 | 200 | 300 (1 row) gaussdb=# SELECT * FROM test_trigger_des_tbl; // The trigger does not take effect. id1 | id2 | id3 -----+-----+----- (0 rows) -- Disable all triggers on the current table. gaussdb=# ALTER TABLE test_trigger_src_tbl DISABLE TRIGGER ALL; |
Deleting a trigger
1 2 3 4 5 |
gaussdb=# DROP TRIGGER insert_trigger ON test_trigger_src_tbl; gaussdb=# DROP TRIGGER update_trigger ON test_trigger_src_tbl; gaussdb=# DROP TRIGGER delete_trigger_renamed ON test_trigger_src_tbl; |
Deleting a function
1 2 3 4 5 |
gaussdb=# DROP FUNCTION tri_insert_func; gaussdb=# DROP FUNCTION tri_update_func; gaussdb=# DROP FUNCTION tri_delete_func; |
1 2 3 |
-- Drop the source table and destination table. gaussdb=# DROP TABLE test_trigger_src_tbl; gaussdb=# DROP TABLE test_trigger_des_tbl; |
Helpful Links
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.