2 -- Create the tables used in the test queries
4 -- T_pkey1 is the primary key table for T_dta1. Entries from T_pkey1
5 -- Cannot be changed or deleted if they are referenced from T_dta1.
7 -- T_pkey2 is the primary key table for T_dta2. If the key values in
8 -- T_pkey2 are changed, the references in T_dta2 follow. If entries
9 -- are deleted, the referencing entries from T_dta2 are deleted too.
10 -- The values for field key2 in T_pkey2 are silently converted to
11 -- upper case on insert/update.
13 create table T_pkey1 (
19 create table T_pkey2 (
39 -- Function to check key existance in T_pkey1
41 create function check_pkey1_exists(int4, bpchar) returns bool as E'
42 if {![info exists GD]} {
43 set GD(plan) [spi_prepare \\
44 "select 1 from T_pkey1 \\
45 where key1 = \\$1 and key2 = \\$2" \\
49 set n [spi_execp -count 1 $GD(plan) [list $1 $2]]
60 CREATE TABLE trigger_test
63 CREATE FUNCTION trigger_data() returns trigger language pltcl as $_$
65 if { [info exists TG_relid] } {
66 set TG_relid "bogus:12345"
69 set dnames [info locals {[a-zA-Z]*} ]
71 foreach key [lsort $dnames] {
73 if { [array exists $key] } {
75 foreach akey [lsort [ array names $key ] ] {
76 if {[string length $str] > 1} { set str "$str, " }
78 set cmd "set val \$$key$cmd"
80 set str "$str$akey: $val"
83 elog NOTICE "$key: $str"
85 set val [eval list "\$$key" ]
86 elog NOTICE "$key: $val"
95 CREATE TRIGGER show_trigger_data_trig
96 BEFORE INSERT OR UPDATE OR DELETE ON trigger_test
97 FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
101 -- Trigger function on every change to T_pkey1
103 create function trig_pkey1_before() returns trigger as E'
105 # Create prepared plans on the first call
107 if {![info exists GD]} {
109 # Plan to check for duplicate key in T_pkey1
111 set GD(plan_pkey1) [spi_prepare \\
112 "select check_pkey1_exists(\\$1, \\$2) as ret" \\
115 # Plan to check for references from T_dta1
117 set GD(plan_dta1) [spi_prepare \\
118 "select 1 from T_dta1 \\
119 where ref1 = \\$1 and ref2 = \\$2" \\
132 # Must check for duplicate key on INSERT
138 # Must check for duplicate key on UPDATE only if
139 # the key changes. In that case we must check for
140 # references to OLD values too.
142 if {[string compare $NEW(key1) $OLD(key1)] != 0} {
146 if {[string compare $NEW(key2) $OLD(key2)] != 0} {
153 # Must only check for references to OLD on DELETE
159 if {$check_new_dup} {
161 # Check for duplicate key
163 spi_execp -count 1 $GD(plan_pkey1) [list $NEW(key1) $NEW(key2)]
166 "duplicate key ''$NEW(key1)'', ''$NEW(key2)'' for T_pkey1"
170 if {$check_old_ref} {
172 # Check for references to OLD
174 set n [spi_execp -count 1 $GD(plan_dta1) [list $OLD(key1) $OLD(key2)]]
177 "key ''$OLD(key1)'', ''$OLD(key2)'' referenced by T_dta1"
182 # Anything is fine - let operation pass through
188 create trigger pkey1_before before insert or update or delete on T_pkey1
189 for each row execute procedure
194 -- Trigger function to check for duplicate keys in T_pkey2
195 -- and to force key2 to be upper case only without leading whitespaces
197 create function trig_pkey2_before() returns trigger as E'
199 # Prepare plan on first call
201 if {![info exists GD]} {
202 set GD(plan_pkey2) [spi_prepare \\
203 "select 1 from T_pkey2 \\
204 where key1 = \\$1 and key2 = \\$2" \\
211 set NEW(key2) [string toupper [string trim $NEW(key2)]]
214 # Check for duplicate key
216 set n [spi_execp -count 1 $GD(plan_pkey2) [list $NEW(key1) $NEW(key2)]]
219 "duplicate key ''$NEW(key1)'', ''$NEW(key2)'' for T_pkey2"
223 # Return modified tuple in NEW
225 return [array get NEW]
229 create trigger pkey2_before before insert or update on T_pkey2
230 for each row execute procedure
235 -- Trigger function to force references from T_dta2 follow changes
236 -- in T_pkey2 or be deleted too. This must be done AFTER the changes
237 -- in T_pkey2 are done so the trigger for primkey check on T_dta2
238 -- fired on our updates will see the new key values in T_pkey2.
240 create function trig_pkey2_after() returns trigger as E'
242 # Prepare plans on first call
244 if {![info exists GD]} {
246 # Plan to update references from T_dta2
248 set GD(plan_dta2_upd) [spi_prepare \\
249 "update T_dta2 set ref1 = \\$3, ref2 = \\$4 \\
250 where ref1 = \\$1 and ref2 = \\$2" \\
251 {int4 bpchar int4 bpchar}]
253 # Plan to delete references from T_dta2
255 set GD(plan_dta2_del) [spi_prepare \\
256 "delete from T_dta2 \\
257 where ref1 = \\$1 and ref2 = \\$2" \\
270 # On update we must let old references follow
272 set NEW(key2) [string toupper $NEW(key2)]
274 if {[string compare $NEW(key1) $OLD(key1)] != 0} {
277 if {[string compare $NEW(key2) $OLD(key2)] != 0} {
283 # On delete we must delete references too
289 if {$old_ref_follow} {
291 # Let old references follow and fire NOTICE message if
294 set n [spi_execp $GD(plan_dta2_upd) \\
295 [list $OLD(key1) $OLD(key2) $NEW(key1) $NEW(key2)]]
298 "updated $n entries in T_dta2 for new key in T_pkey2"
302 if {$old_ref_delete} {
304 # delete references and fire NOTICE message if
307 set n [spi_execp $GD(plan_dta2_del) \\
308 [list $OLD(key1) $OLD(key2)]]
311 "deleted $n entries from T_dta2"
319 create trigger pkey2_after after update or delete on T_pkey2
320 for each row execute procedure
325 -- Generic trigger function to check references in T_dta1 and T_dta2
327 create function check_primkey() returns trigger as E'
329 # For every trigger/relation pair we create
330 # a saved plan and hold them in GD
332 set plankey [list "plan" $TG_name $TG_relid]
333 set planrel [list "relname" $TG_relid]
336 # Extract the pkey relation name
338 set keyidx [expr [llength $args] / 2]
339 set keyrel [string tolower [lindex $args $keyidx]]
341 if {![info exists GD($plankey)]} {
343 # We must prepare a new plan. Build up a query string
344 # for the primary key check.
346 set keylist [lrange $args [expr $keyidx + 1] end]
348 set query "select 1 from $keyrel"
352 foreach key $keylist {
353 set key [string tolower $key]
355 # Add the qual part to the query string
357 append query "$qual $key = \\$$idx"
361 # Lookup the fields type in pg_attribute
363 set n [spi_exec "select T.typname \\
364 from pg_catalog.pg_type T, pg_catalog.pg_attribute A, pg_catalog.pg_class C \\
365 where C.relname = ''[quote $keyrel]'' \\
366 and C.oid = A.attrelid \\
367 and A.attname = ''[quote $key]'' \\
368 and A.atttypid = T.oid"]
370 elog ERROR "table $keyrel doesn''t have a field named $key"
374 # Append the fields type to the argument type list
376 lappend typlist $typname
383 set GD($plankey) [spi_prepare $query $typlist]
386 # Lookup and remember the table name for later error messages
388 spi_exec "select relname from pg_catalog.pg_class \\
389 where oid = ''$TG_relid''::oid"
390 set GD($planrel) $relname
394 # Build the argument list from the NEW row
398 foreach arg [lrange $args 0 $keyidx] {
399 lappend arglist $NEW($arg)
403 # Check for the primary key
405 set n [spi_execp -count 1 $GD($plankey) $arglist]
407 elog ERROR "key for $GD($planrel) not in $keyrel"
417 create trigger dta1_before before insert or update on T_dta1
418 for each row execute procedure
419 check_primkey('ref1', 'ref2', 'T_pkey1', 'key1', 'key2');
422 create trigger dta2_before before insert or update on T_dta2
423 for each row execute procedure
424 check_primkey('ref1', 'ref2', 'T_pkey2', 'key1', 'key2');
427 create function tcl_int4add(int4,int4) returns int4 as '
428 return [expr $1 + $2]
431 -- We use split(n) as a quick-and-dirty way of parsing the input array
432 -- value, which comes in as a string like '{1,2}'. There are better ways...
434 create function tcl_int4_accum(int4[], int4) returns int4[] as '
435 set state [split $1 "{,}"]
436 set newsum [expr {[lindex $state 1] + $2}]
437 set newcnt [expr {[lindex $state 2] + 1}]
438 return "{$newsum,$newcnt}"
441 create function tcl_int4_avg(int4[]) returns int4 as '
442 set state [split $1 "{,}"]
443 if {[lindex $state 2] == 0} { return_null }
444 return [expr {[lindex $state 1] / [lindex $state 2]}]
447 create aggregate tcl_avg (
448 sfunc = tcl_int4_accum,
451 finalfunc = tcl_int4_avg,
455 create aggregate tcl_sum (
462 create function tcl_int4lt(int4,int4) returns bool as '
469 create function tcl_int4le(int4,int4) returns bool as '
476 create function tcl_int4eq(int4,int4) returns bool as '
483 create function tcl_int4ge(int4,int4) returns bool as '
490 create function tcl_int4gt(int4,int4) returns bool as '
500 procedure = tcl_int4lt
503 create operator @<= (
506 procedure = tcl_int4le
512 procedure = tcl_int4eq
515 create operator @>= (
518 procedure = tcl_int4ge
524 procedure = tcl_int4gt
527 create function tcl_int4cmp(int4,int4) returns int4 as '
537 CREATE OPERATOR CLASS tcl_int4_ops
538 FOR TYPE int4 USING btree AS
544 FUNCTION 1 tcl_int4cmp(int4,int4) ;