|
| 1 | +SET search_path TO common_oltp; |
| 2 | + |
| 3 | +CREATE OR REPLACE FUNCTION "common_oltp"."notify_trigger_common_oltp" () RETURNS trigger |
| 4 | + VOLATILE |
| 5 | +AS $body$ |
| 6 | +DECLARE |
| 7 | + rec RECORD; |
| 8 | + payload TEXT; |
| 9 | + column_name TEXT; |
| 10 | + column_value TEXT; |
| 11 | + payload_items TEXT[]; |
| 12 | + uniquecolumn TEXT; |
| 13 | + logtime TEXT; |
| 14 | + payloadseqid INTEGER; |
| 15 | +BEGIN |
| 16 | + CASE TG_OP |
| 17 | + WHEN 'INSERT', 'UPDATE' THEN |
| 18 | + rec := NEW; |
| 19 | + WHEN 'DELETE' THEN |
| 20 | + rec := OLD; |
| 21 | + ELSE |
| 22 | + RAISE EXCEPTION 'Unknown TG_OP: "%". Should not occur!', TG_OP; |
| 23 | + END CASE; |
| 24 | + raise notice 'table name : %', TG_TABLE_NAME; |
| 25 | + RAISE info 'hello world'; |
| 26 | + -- Get required fields |
| 27 | + FOREACH column_name IN ARRAY TG_ARGV LOOP |
| 28 | + EXECUTE format('SELECT $1.%I::TEXT', column_name) |
| 29 | + INTO column_value |
| 30 | + USING rec; |
| 31 | + case |
| 32 | + when |
| 33 | + column_name = 'upload_document' then |
| 34 | + -- RAISE NOTICE 'upload_document boolean'; |
| 35 | + if column_value = 'false' then |
| 36 | + column_value = '0'; |
| 37 | + else |
| 38 | + column_value = '1'; |
| 39 | + end if; |
| 40 | + when |
| 41 | + column_name = 'upload_document_required' then |
| 42 | + -- RAISE NOTICE 'upload_document_required boolean'; |
| 43 | + if column_value = 'false' then |
| 44 | + column_value = '0'; |
| 45 | + else |
| 46 | + column_value = '1'; |
| 47 | + end if; |
| 48 | + when |
| 49 | + column_name = 'identify_email_enabled' then |
| 50 | + if column_value = 'false' then |
| 51 | + column_value = '0'; |
| 52 | + else |
| 53 | + column_value = '1'; |
| 54 | + end if; |
| 55 | + when |
| 56 | + column_name = 'identify_handle_enabled' then |
| 57 | + if column_value = 'false' then |
| 58 | + column_value = '0'; |
| 59 | + else |
| 60 | + column_value = '1'; |
| 61 | + end if; |
| 62 | + when |
| 63 | + column_name = 'create_date' then |
| 64 | + column_value := (select to_char (column_value::timestamp, 'YYYY-MM-DD HH24:MI:SS.MS')); |
| 65 | + when |
| 66 | + column_name = 'modify_date' then |
| 67 | + column_value := (select to_char (column_value::timestamp, 'YYYY-MM-DD HH24:MI:SS.MS')); |
| 68 | + -- when |
| 69 | + -- column_name = 'achievement_date' then |
| 70 | + --column_value := (select to_date (column_value, 'MM/DD/YYYY')); |
| 71 | + --column_value := (select to_date (column_value)); |
| 72 | + --when |
| 73 | + --column_name = 'password' then |
| 74 | + --column_value := regexp_replace(column_value, '\s', '', 'g'); |
| 75 | + --column_value := regexp_replace(column_value, E'[\\n\\r]+', '\n\r', 'g'); |
| 76 | + else |
| 77 | + -- RAISE NOTICE ' not boolean'; |
| 78 | + end case; |
| 79 | + payload_items := array_append(payload_items, '"' || replace(column_name, '"', '\"') || '":"' || replace(column_value, '"', '\"') || '"'); |
| 80 | + END LOOP; |
| 81 | + --logtime := (select date_display_tz()); |
| 82 | + logtime := (SELECT to_char (now()::timestamptz at time zone 'UTC', 'YYYY-MM-DD"T"HH24:MI:SS"Z"')); |
| 83 | + payloadseqid := (select nextval('payloadsequence'::regclass)); |
| 84 | + |
| 85 | + uniquecolumn := (SELECT c.column_name |
| 86 | + FROM information_schema.key_column_usage AS c |
| 87 | + LEFT JOIN information_schema.table_constraints AS t |
| 88 | + ON t.constraint_name = c.constraint_name |
| 89 | + WHERE t.table_name = TG_TABLE_NAME AND t.constraint_type = 'PRIMARY KEY' LIMIT 1); |
| 90 | + |
| 91 | + if (uniquecolumn = '') IS NOT FALSE then |
| 92 | + uniquecolumn := 'Not-Available'; |
| 93 | + end if; |
| 94 | + |
| 95 | + -- Build the payload |
| 96 | + payload := '' |
| 97 | + || '{' |
| 98 | + || '"topic":"' || 'test.db.postgres.sync' || '",' |
| 99 | + || '"originator":"' || 'tc-postgres-delta-processor' || '",' |
| 100 | + || '"timestamp":"' || logtime || '",' |
| 101 | + || '"mime-type":"' || 'application/json' || '",' |
| 102 | + || '"payload": {' |
| 103 | + || '"payloadseqid":"' || payloadseqid || '",' |
| 104 | + || '"Uniquecolumn":"' || uniquecolumn || '",' |
| 105 | + || '"operation":"' || TG_OP || '",' |
| 106 | + || '"schema":"' || TG_TABLE_SCHEMA || '",' |
| 107 | + || '"table":"' || TG_TABLE_NAME || '",' |
| 108 | + || '"data": {' || array_to_string(payload_items, ',') || '}' |
| 109 | + || '}}'; |
| 110 | + |
| 111 | + -- Notify the channel |
| 112 | + PERFORM pg_notify('test_db_notifications', payload); |
| 113 | + |
| 114 | + RETURN rec; |
| 115 | +END; |
| 116 | +$body$ LANGUAGE plpgsql; |
| 117 | + |
| 118 | +CREATE TRIGGER "pg_email_trigger" |
| 119 | + AFTER INSERT OR DELETE OR UPDATE ON email |
| 120 | + FOR EACH ROW |
| 121 | +EXECUTE PROCEDURE notify_trigger_common_oltp('user_id', 'email_id', 'email_type_id', 'address', 'primary_ind', 'status_id'); |
| 122 | + |
| 123 | +CREATE TRIGGER "pg_security_user_trigger" |
| 124 | + AFTER INSERT OR DELETE OR UPDATE ON security_user |
| 125 | + FOR EACH ROW |
| 126 | +EXECUTE PROCEDURE notify_trigger_common_oltp('login_id', 'user_id', 'password', 'create_user_id'); |
| 127 | + |
| 128 | + |
| 129 | +CREATE TRIGGER "pg_user_achievement_trigger" |
| 130 | + AFTER INSERT OR DELETE OR UPDATE ON user_achievement |
| 131 | + FOR EACH ROW |
| 132 | +EXECUTE PROCEDURE notify_trigger_common_oltp('user_id', 'achievement_date', 'achievement_type_id', 'description', 'create_date'); |
| 133 | + |
| 134 | +CREATE TRIGGER "pg_user_group_xref_trigger" |
| 135 | + AFTER INSERT OR DELETE OR UPDATE ON user_group_xref |
| 136 | + FOR EACH ROW |
| 137 | +EXECUTE PROCEDURE notify_trigger_common_oltp('user_group_id', 'login_id', 'group_id', 'create_user_id', 'security_status_id'); |
| 138 | + |
| 139 | +CREATE TRIGGER "pg_user_trigger" |
| 140 | + AFTER INSERT OR DELETE OR UPDATE ON user |
| 141 | + FOR EACH ROW |
| 142 | +EXECUTE PROCEDURE notify_trigger_common_oltp('user_id', 'first_name', 'last_name', 'handle', 'status', 'activation_code', 'reg_source', 'utm_source', 'utm_medium', 'utm_campaign'); |
| 143 | + |
| 144 | +--drop SEQUENCE sequence_user_group_seq; |
| 145 | +CREATE SEQUENCE sequence_user_group_seq INCREMENT BY 1 MINVALUE 1 MAXVALUE 9223372036854775807 START |
| 146 | +WITH 600000000 NO CYCLE; |
| 147 | + |
| 148 | + |
| 149 | +--drop SEQUENCE sequence_email_seq; |
| 150 | +CREATE SEQUENCE sequence_email_seq INCREMENT BY 1 MINVALUE 1 MAXVALUE 9223372036854775807 START |
| 151 | +WITH 60000000 NO CYCLE; |
| 152 | + |
| 153 | + |
| 154 | +SET search_path TO informixoltp; |
| 155 | + |
| 156 | +CREATE OR REPLACE FUNCTION "informixoltp"."notify_trigger_informixoltp" () RETURNS trigger |
| 157 | + VOLATILE |
| 158 | +AS $body$ |
| 159 | +DECLARE |
| 160 | + rec RECORD; |
| 161 | + payload TEXT; |
| 162 | + column_name TEXT; |
| 163 | + column_value TEXT; |
| 164 | + payload_items TEXT[]; |
| 165 | + uniquecolumn TEXT; |
| 166 | + logtime TEXT; |
| 167 | + payloadseqid INTEGER; |
| 168 | +BEGIN |
| 169 | + CASE TG_OP |
| 170 | + WHEN 'INSERT', 'UPDATE' THEN |
| 171 | + rec := NEW; |
| 172 | + WHEN 'DELETE' THEN |
| 173 | + rec := OLD; |
| 174 | + ELSE |
| 175 | + RAISE EXCEPTION 'Unknown TG_OP: "%". Should not occur!', TG_OP; |
| 176 | + END CASE; |
| 177 | + raise notice 'table name : %', TG_TABLE_NAME; |
| 178 | + RAISE info 'hello world'; |
| 179 | + -- Get required fields |
| 180 | + FOREACH column_name IN ARRAY TG_ARGV LOOP |
| 181 | + EXECUTE format('SELECT $1.%I::TEXT', column_name) |
| 182 | + INTO column_value |
| 183 | + USING rec; |
| 184 | + case |
| 185 | + when |
| 186 | + column_name = 'upload_document' then |
| 187 | + -- RAISE NOTICE 'upload_document boolean'; |
| 188 | + if column_value = 'false' then |
| 189 | + column_value = '0'; |
| 190 | + else |
| 191 | + column_value = '1'; |
| 192 | + end if; |
| 193 | + when |
| 194 | + column_name = 'upload_document_required' then |
| 195 | + -- RAISE NOTICE 'upload_document_required boolean'; |
| 196 | + if column_value = 'false' then |
| 197 | + column_value = '0'; |
| 198 | + else |
| 199 | + column_value = '1'; |
| 200 | + end if; |
| 201 | + when |
| 202 | + column_name = 'identify_email_enabled' then |
| 203 | + if column_value = 'false' then |
| 204 | + column_value = '0'; |
| 205 | + else |
| 206 | + column_value = '1'; |
| 207 | + end if; |
| 208 | + when |
| 209 | + column_name = 'identify_handle_enabled' then |
| 210 | + if column_value = 'false' then |
| 211 | + column_value = '0'; |
| 212 | + else |
| 213 | + column_value = '1'; |
| 214 | + end if; |
| 215 | + when |
| 216 | + column_name = 'create_date' then |
| 217 | + column_value := (select to_char (column_value::timestamp, 'YYYY-MM-DD HH24:MI:SS.MS')); |
| 218 | + when |
| 219 | + column_name = 'modify_date' then |
| 220 | + column_value := (select to_char (column_value::timestamp, 'YYYY-MM-DD HH24:MI:SS.MS')); |
| 221 | + -- when |
| 222 | + -- column_name = 'achievement_date' then |
| 223 | + --column_value := (select to_date (column_value, 'MM/DD/YYYY')); |
| 224 | + --column_value := (select to_date (column_value)); |
| 225 | + --when |
| 226 | + --column_name = 'password' then |
| 227 | + --column_value := regexp_replace(column_value, '\s', '', 'g'); |
| 228 | + --column_value := regexp_replace(column_value, E'[\\n\\r]+', '\n\r', 'g'); |
| 229 | + else |
| 230 | + -- RAISE NOTICE ' not boolean'; |
| 231 | + end case; |
| 232 | + payload_items := array_append(payload_items, '"' || replace(column_name, '"', '\"') || '":"' || replace(column_value, '"', '\"') || '"'); |
| 233 | + END LOOP; |
| 234 | + --logtime := (select date_display_tz()); |
| 235 | + logtime := (SELECT to_char (now()::timestamptz at time zone 'UTC', 'YYYY-MM-DD"T"HH24:MI:SS"Z"')); |
| 236 | + payloadseqid := (select nextval('payloadsequence'::regclass)); |
| 237 | + |
| 238 | + uniquecolumn := (SELECT c.column_name |
| 239 | + FROM information_schema.key_column_usage AS c |
| 240 | + LEFT JOIN information_schema.table_constraints AS t |
| 241 | + ON t.constraint_name = c.constraint_name |
| 242 | + WHERE t.table_name = TG_TABLE_NAME AND t.constraint_type = 'PRIMARY KEY' LIMIT 1); |
| 243 | + |
| 244 | + if (uniquecolumn = '') IS NOT FALSE then |
| 245 | + uniquecolumn := 'Not-Available'; |
| 246 | + end if; |
| 247 | + |
| 248 | + -- Build the payload |
| 249 | + payload := '' |
| 250 | + || '{' |
| 251 | + || '"topic":"' || 'test.db.postgres.sync' || '",' |
| 252 | + || '"originator":"' || 'tc-postgres-delta-processor' || '",' |
| 253 | + || '"timestamp":"' || logtime || '",' |
| 254 | + || '"mime-type":"' || 'application/json' || '",' |
| 255 | + || '"payload": {' |
| 256 | + || '"payloadseqid":"' || payloadseqid || '",' |
| 257 | + || '"Uniquecolumn":"' || uniquecolumn || '",' |
| 258 | + || '"operation":"' || TG_OP || '",' |
| 259 | + || '"schema":"' || TG_TABLE_SCHEMA || '",' |
| 260 | + || '"table":"' || TG_TABLE_NAME || '",' |
| 261 | + || '"data": {' || array_to_string(payload_items, ',') || '}' |
| 262 | + || '}}'; |
| 263 | + |
| 264 | + -- Notify the channel |
| 265 | + PERFORM pg_notify('test_db_notifications', payload); |
| 266 | + |
| 267 | + RETURN rec; |
| 268 | +END; |
| 269 | +$body$ LANGUAGE plpgsql; |
| 270 | + |
| 271 | + |
| 272 | +CREATE TRIGGER "pg_algo_rating" |
| 273 | + AFTER INSERT OR DELETE OR UPDATE ON algo_rating |
| 274 | + FOR EACH ROW |
| 275 | +EXECUTE PROCEDURE notify_trigger_informixoltp('coder_id', 'rating', 'vol', 'round_id', 'num_ratings', 'algo_rating_type_id', 'modify_date'); |
| 276 | + |
| 277 | +CREATE TRIGGER "pg_coder" |
| 278 | + AFTER INSERT OR DELETE OR UPDATE ON coder |
| 279 | + FOR EACH ROW |
| 280 | +EXECUTE PROCEDURE notify_trigger_informixoltp('coder_id', 'quote', 'coder_type_id', 'comp_country_code', 'display_quote', 'quote_location', 'quote_color', 'display_banner', 'banner_style'); |
0 commit comments