diff --git a/contrib/spi/Makefile b/contrib/spi/Makefile index 2784d69b9e..8826ed23c0 100644 --- a/contrib/spi/Makefile +++ b/contrib/spi/Makefile @@ -14,6 +14,7 @@ TARGETS= refint$(DLSUFFIX) refint.sql CLEANFILES+= $(TARGETS) all:: $(TARGETS) + rm -f *.obj *.pic %.sql: %.source rm -f $@; \ @@ -22,4 +23,4 @@ all:: $(TARGETS) -e "s:_DLSUFFIX_:$(DLSUFFIX):g" < $< > $@ clean: - rm -f $(TARGETS) refint.o + rm -f $(TARGETS) *.[op]* diff --git a/contrib/spi/README b/contrib/spi/README new file mode 100644 index 0000000000..932181f309 --- /dev/null +++ b/contrib/spi/README @@ -0,0 +1,37 @@ + +Here are general trigger functions provided as workable examples +of using SPI and triggers. "General" means that functions may be +used for defining triggers for any tables but you have to specify +table/field names (as described below) while creating a trigger. + +1. refint.c - functions for implementing referential integrity. + +check_primary_key () is to used for foreign keys of a table. + + You are to create trigger (BEFORE INSERT OR UPDATE) using this +function on a table referencing another table. You are to specify +as function arguments: triggered table column names which correspond +to foreign key, referenced table name and column names in referenced +table which correspond to primary/unique key. + You may create as many triggers as you need - one trigger for +one reference. + +check_foreign_key () is to used for primary/unique keys of a table. + + You are to create trigger (BEFORE DELETE OR UPDATE) using this +function on a table referenced by another table(s). You are to specify +as function arguments: number of references for which function has to +performe checking, action if referencing key found ('cascade' - to delete +corresponding foreign key, 'restrict' - to abort transaction if foreign keys +exist, 'setnull' - to set foreign key referencing primary/unique key +being deleted to null), triggered table column names which correspond +to primary/unique key, referencing table name and column names corresponding +to foreign key (, ... - as many referencing tables/keys as specified +by first argument). + Note, that NOT NULL constraint and unique index have to be defined +by youself. + + There are examples in refint.example and regression tests +(sql/triggers.sql). + + diff --git a/contrib/spi/refint.example b/contrib/spi/refint.example new file mode 100644 index 0000000000..1300e81654 --- /dev/null +++ b/contrib/spi/refint.example @@ -0,0 +1,82 @@ +--Column ID of table A is primary key: + +CREATE TABLE A ( + ID int4 not null +); +CREATE UNIQUE INDEX AI ON A (ID); + +--Columns REFB of table B and REFC of C are foreign keys referenting ID of A: + +CREATE TABLE B ( + REFB int4 +); +CREATE INDEX BI ON B (REFB); + +CREATE TABLE C ( + REFC int4 +); +CREATE INDEX CI ON C (REFC); + +--Trigger for table A: + +CREATE TRIGGER AT BEFORE DELETE OR UPDATE ON A FOR EACH ROW +EXECUTE PROCEDURE +check_foreign_key (2, 'cascade', 'ID', 'B', 'REFB', 'C', 'REFC'); +/* +2 - means that check must be performed for foreign keys of 2 tables. +cascade - defines that corresponding keys must be deleted. +ID - name of primary key column in triggered table (A). You may + use as many columns as you need. +B - name of (first) table with foreign keys. +REFB - name of foreign key column in this table. You may use as many + columns as you need, but number of key columns in referenced + table (A) must be the same. +C - name of second table with foreign keys. +REFC - name of foreign key column in this table. +*/ + +--Trigger for table B: + +CREATE TRIGGER BT BEFORE INSERT OR UPDATE ON B FOR EACH ROW +EXECUTE PROCEDURE +check_primary_key ('REFB', 'A', 'ID'); + +/* +REFB - name of foreign key column in triggered (B) table. You may use as + many columns as you need, but number of key columns in referenced + table must be the same. +A - referenced table name. +ID - name of primary key column in referenced table. +*/ + +--Trigger for table C: + +CREATE TRIGGER CT BEFORE INSERT OR UPDATE ON C FOR EACH ROW +EXECUTE PROCEDURE +check_primary_key ('REFC', 'A', 'ID'); + +-- Now try + +INSERT INTO A VALUES (10); +INSERT INTO A VALUES (20); +INSERT INTO A VALUES (30); +INSERT INTO A VALUES (40); +INSERT INTO A VALUES (50); + +INSERT INTO B VALUES (1); -- invalid reference +INSERT INTO B VALUES (10); +INSERT INTO B VALUES (30); +INSERT INTO B VALUES (30); + +INSERT INTO C VALUES (11); -- invalid reference +INSERT INTO C VALUES (20); +INSERT INTO C VALUES (20); +INSERT INTO C VALUES (30); + +DELETE FROM A WHERE ID = 10; +DELETE FROM A WHERE ID = 20; +DELETE FROM A WHERE ID = 30; + +SELECT * FROM A; +SELECT * FROM B; +SELECT * FROM C;