|
| 1 | +-- ######################## |
| 2 | +-- ######## TABLES ######## |
| 3 | +-- ######################## |
| 4 | + |
| 5 | +-- Registered deciders and the respectful events that these deciders can publish (decider can publish and/or source its own state from these event types only) |
| 6 | +CREATE TABLE IF NOT EXISTS deciders |
| 7 | +( |
| 8 | + -- decider name/type |
| 9 | + "decider" TEXT NOT NULL, |
| 10 | + -- event name/type that this decider can publish |
| 11 | + "event" TEXT NOT NULL, |
| 12 | + PRIMARY KEY ("decider", "event") |
| 13 | +); |
| 14 | + |
| 15 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'RestaurantCreated'); |
| 16 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'RestaurantNotCreated'); |
| 17 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'RestaurantMenuChanged'); |
| 18 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'RestaurantMenuNotChanged'); |
| 19 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'OrderPlaced'); |
| 20 | +INSERT INTO deciders ("decider", "event") VALUES ('Restaurant', 'OrderNotPlaced'); |
| 21 | +INSERT INTO deciders ("decider", "event") VALUES ('Order', 'OrderCreated'); |
| 22 | +INSERT INTO deciders ("decider", "event") VALUES ('Order', 'OrderPrepared'); |
| 23 | +INSERT INTO deciders ("decider", "event") VALUES ('Order', 'OrderNotCreated'); |
| 24 | +INSERT INTO deciders ("decider", "event") VALUES ('Order', 'OrderNotPrepared'); |
| 25 | + |
| 26 | + |
| 27 | +-- Events |
| 28 | +CREATE TABLE IF NOT EXISTS events |
| 29 | +( |
| 30 | + -- event name/type. Part of a composite foreign key to `deciders` |
| 31 | + "event" TEXT NOT NULL, |
| 32 | + -- event ID. This value is used by the next event as it's `previous_id` value to guard against a Lost-EventModel problem / optimistic locking. |
| 33 | + "event_id" UUID NOT NULL UNIQUE, |
| 34 | + -- decider name/type. Part of a composite foreign key to `deciders` |
| 35 | + "decider" TEXT NOT NULL, |
| 36 | + -- business identifier for the decider |
| 37 | + "decider_id" TEXT NOT NULL, |
| 38 | + -- event data in JSON format |
| 39 | + "data" JSONB NOT NULL, |
| 40 | + -- command ID causing this event |
| 41 | + "command_id" UUID NULL, |
| 42 | + -- previous event uuid; null for first event; null does not trigger UNIQUE constraint; we defined a function `check_first_event_for_decider` |
| 43 | + "previous_id" UUID UNIQUE, |
| 44 | + -- indicator if the event stream for the `decider_id` is final |
| 45 | + "final" BOOLEAN NOT NULL DEFAULT FALSE, |
| 46 | + -- The timestamp of the event insertion. AUTOPOPULATES—DO NOT INSERT |
| 47 | + "created_at" TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL, |
| 48 | + -- ordering sequence/offset for all events in all deciders. AUTOPOPULATES—DO NOT INSERT |
| 49 | + "offset" BIGSERIAL PRIMARY KEY, |
| 50 | + FOREIGN KEY ("decider", "event") REFERENCES deciders ("decider", "event") |
| 51 | +); |
| 52 | + |
| 53 | + |
| 54 | +CREATE INDEX IF NOT EXISTS decider_index ON events ("decider_id", "offset"); |
| 55 | + |
| 56 | +-- ######################## |
| 57 | +-- ##### SIDE EFFECTS ##### |
| 58 | +-- ######################## |
| 59 | + |
| 60 | +-- Many things that can be done using triggers can also be implemented using the Postgres rule system. |
| 61 | +-- What currently cannot be implemented by rules are some kinds of constraints. |
| 62 | +-- It is possible, to place a qualified rule that rewrites a query to NOTHING if the value of a column does not appear in another table. |
| 63 | +-- But then the data is silently thrown away, and that's not a good idea. |
| 64 | +-- If checks for valid values are required, and in the case of an invalid value an error message should be generated, it must be done by a trigger for now. |
| 65 | + |
| 66 | +-- SIDE EFFECT (rule): immutable decider - ignore deleting already registered events |
| 67 | +--CREATE OR REPLACE RULE ignore_delete_decider_events AS ON DELETE TO deciders |
| 68 | +-- DO INSTEAD NOTHING; |
| 69 | + |
| 70 | +-- SIDE EFFECT (rule): immutable decider - ignore updating already registered events |
| 71 | +--CREATE OR REPLACE RULE ignore_update_decider_events AS ON UPDATE TO deciders |
| 72 | +-- DO INSTEAD NOTHING; |
| 73 | + |
| 74 | +-- SIDE EFFECT (rule): immutable events - ignore delete |
| 75 | +CREATE OR REPLACE RULE ignore_delete_events AS ON DELETE TO events |
| 76 | + DO INSTEAD NOTHING; |
| 77 | + |
| 78 | +-- SIDE EFFECT (rule): immutable events - ignore update |
| 79 | +CREATE OR REPLACE RULE ignore_update_events AS ON UPDATE TO events |
| 80 | + DO INSTEAD NOTHING; |
| 81 | + |
| 82 | + |
| 83 | +-- SIDE EFFECT (trigger): Can only use null previousId for first event in an decider |
| 84 | +CREATE OR REPLACE FUNCTION check_first_event_for_decider() RETURNS trigger AS |
| 85 | +' |
| 86 | + BEGIN |
| 87 | + IF (NEW.previous_id IS NULL |
| 88 | + AND EXISTS(SELECT 1 |
| 89 | + FROM events |
| 90 | + WHERE NEW.decider_id = decider_id |
| 91 | + AND NEW.decider = decider)) |
| 92 | + THEN |
| 93 | + RAISE EXCEPTION ''previous_id can only be null for first decider event''; |
| 94 | + END IF; |
| 95 | + RETURN NEW; |
| 96 | + END; |
| 97 | +' |
| 98 | + LANGUAGE plpgsql; |
| 99 | + |
| 100 | +DROP TRIGGER IF EXISTS t_check_first_event_for_decider ON events; |
| 101 | +CREATE TRIGGER t_check_first_event_for_decider |
| 102 | + BEFORE INSERT |
| 103 | + ON events |
| 104 | + FOR EACH ROW |
| 105 | +EXECUTE FUNCTION check_first_event_for_decider(); |
| 106 | + |
| 107 | + |
| 108 | +-- SIDE EFFECT (trigger): can only append events if the decider_id stream is not finalized already |
| 109 | +CREATE OR REPLACE FUNCTION check_final_event_for_decider() RETURNS trigger AS |
| 110 | +' |
| 111 | + BEGIN |
| 112 | + IF EXISTS(SELECT 1 |
| 113 | + FROM events |
| 114 | + WHERE NEW.decider_id = decider_id |
| 115 | + AND "final" = TRUE |
| 116 | + AND NEW.decider = decider) |
| 117 | + THEN |
| 118 | + RAISE EXCEPTION ''last event for this decider stream is already final. the stream is closed, you can not append events to it.''; |
| 119 | + END IF; |
| 120 | + RETURN NEW; |
| 121 | + END; |
| 122 | +' |
| 123 | + LANGUAGE plpgsql; |
| 124 | + |
| 125 | +DROP TRIGGER IF EXISTS t_check_final_event_for_decider ON events; |
| 126 | +CREATE TRIGGER t_check_final_event_for_decider |
| 127 | + BEFORE INSERT |
| 128 | + ON events |
| 129 | + FOR EACH ROW |
| 130 | +EXECUTE FUNCTION check_final_event_for_decider(); |
| 131 | + |
| 132 | + |
| 133 | +-- SIDE EFFECT (trigger): previousId must be in the same decider as the event |
| 134 | +CREATE OR REPLACE FUNCTION check_previous_id_in_same_decider() RETURNS trigger AS |
| 135 | +' |
| 136 | + BEGIN |
| 137 | + IF (NEW.previous_id IS NOT NULL |
| 138 | + AND NOT EXISTS(SELECT 1 |
| 139 | + FROM events |
| 140 | + WHERE NEW.previous_id = event_id |
| 141 | + AND NEW.decider_id = decider_id |
| 142 | + AND NEW.decider = decider)) |
| 143 | + THEN |
| 144 | + RAISE EXCEPTION ''previous_id must be in the same decider''; |
| 145 | + END IF; |
| 146 | + RETURN NEW; |
| 147 | + END; |
| 148 | +' |
| 149 | + LANGUAGE plpgsql; |
| 150 | + |
| 151 | +DROP TRIGGER IF EXISTS t_check_previous_id_in_same_decider ON events; |
| 152 | +CREATE TRIGGER t_check_previous_id_in_same_decider |
| 153 | + BEFORE INSERT |
| 154 | + ON events |
| 155 | + FOR EACH ROW |
| 156 | +EXECUTE FUNCTION check_previous_id_in_same_decider(); |
| 157 | + |
0 commit comments