├── README.md ├── data.sql ├── functions.sql ├── immutable.sql ├── scratch.sql ├── structure.sql └── trigger.sql /README.md: -------------------------------------------------------------------------------- 1 | # postgresql-event-sourcing 2 | 3 | Experiment using PostgreSQL as a natively event sourcing database. 4 | 5 | Uses triggers and functions to manage projections transactionally. 6 | 7 | The basic flow of action is: 8 | 9 | event -> after insert trigger -> trigger function -> projection function -> projection 10 | 11 | The advantage of this model is that triggers ensure the projections are always up to date, but we do not lose the ability to replay the event stream with the same logic. 12 | 13 | 14 | ### Events 15 | 16 | Event Sourcing ensures that all changes to application state are stored as a sequence of events. 17 | 18 | Events are stored in an `events` table. 19 | 20 | We assume that all objects/entities in the system have a globally unique identifier. 21 | 22 | | Column | Details | 23 | |---------|-------------------------| 24 | | id | Primary Key | 25 | | uuid | Unique ID of the entity the event references | 26 | | type | The event type, used when building projections | 27 | | body | Event data as JSON | 28 | | inserted_at | timestamp of event insert | 29 | 30 | 31 | ```sql 32 | CREATE TABLE "events" ( 33 | "id" serial primary key not null, 34 | "uuid" uuid NOT NULL, 35 | "type" text NOT NULL, 36 | "body" jsonb NOT NULL, 37 | "inserted_at" timestamp(6) NOT NULL DEFAULT statement_timestamp() 38 | ); 39 | ``` 40 | 41 | An example event, tracking an update to the name of the user identified by a uuid: 42 | 43 | ```sql 44 | insert into events (type, uuid, body) 45 | values ('user_update', '11111111-1111-1111-1111-111111111111', '{"name": "blah"}'); 46 | ``` 47 | 48 | ### Projection Triggers 49 | 50 | Use `after insert` triggers on the `events` table to handle the incoming event actions. 51 | 52 | In order to replay the events outside of the trigger mechanism, we wrap a general projection function inside the trigger. This will make more sense in a moment. 53 | 54 | Below we create a trigger function and a trigger to execute. 55 | The trigger uses a conditional to only fire when the appropriate event type has been inserted. 56 | 57 | ```sql 58 | create or replace function fn_trigger_user_create() returns trigger 59 | security definer 60 | language plpgsql 61 | as $$ 62 | begin 63 | perform fn_project_user_create(new.uuid, new.body); 64 | return new; 65 | end; 66 | $$; 67 | 68 | create trigger event_insert_user_create after insert on events 69 | for each row 70 | when (new.type = 'user_create') 71 | execute procedure fn_trigger_user_insert(); 72 | ``` 73 | 74 | ### Projection Functions 75 | 76 | A projection function does the actual work of handling the event data and mapping to the appropriate projection. 77 | 78 | Multiple triggers and multiple functions can be added to handle different aspects of the same event type if required. 79 | 80 | Assuming a `users` table with a `name` and `uuid`, the following function inserts a new user record into the table based on the `user_create` event. 81 | 82 | ```sql 83 | create or replace function fn_project_user_create(uuid uuid, body jsonb) returns integer 84 | security definer 85 | language plpgsql as $$ 86 | declare result int; 87 | begin 88 | insert into users(uuid, name, inserted_at, updated_at) 89 | values(uuid, body->>'name', NOW(), NOW()) 90 | returning id into result; 91 | return result; 92 | end; 93 | $$; 94 | ``` 95 | 96 | JSON can be referenced using the native operators in PostgreSQL 9.5. `body->>'name'` extracts the value of the name field from the body JSON. 97 | 98 | Any constraints on the table will also be enforced, ensuring referential integrity. 99 | 100 | 101 | ### Replay Event Stream 102 | 103 | Using projection functions means that at any point the events can be replayed, simply by calling the function and passing the correct identifier and data. 104 | 105 | 106 | The following code replays all `user_create` events in order 107 | 108 | ```sql 109 | do language plpgsql $$ 110 | declare 111 | e record; 112 | begin 113 | for e in select uuid body from events where type = 'user_create' order by inserted_at asc loop 114 | perform fn_project_user_create(e.uuid, e.body); 115 | end loop; 116 | end; 117 | $$; 118 | ``` 119 | 120 | Any valid query can be used as the basis for the replay loop, and any combination of valid events. 121 | 122 | The following code replays all events for the user identified by the specified uuid: 123 | 124 | ```sql 125 | do language plpgsql $$ 126 | declare 127 | e record; 128 | begin 129 | for e in select type, uuid, body from events where uuid = '11111111-1111-1111-1111-111111111111' order by inserted_at asc loop 130 | case e.type 131 | when 'user_create' then 132 | perform fn_project_user_create(e.uuid, e.body); 133 | when 'user_update' then 134 | perform fn_project_user_update(e.uuid, e.body); 135 | end case; 136 | end loop; 137 | end; 138 | $$; 139 | ``` 140 | All of these functions will be executed in the same transaction block. 141 | This doesn't particularly matter in an event sourced system, but it is good to know. 142 | 143 | PostgreSQL is not just limited to processing events iteratively. 144 | 145 | Below is an example of using a materialized view to project the user data. 146 | 147 | ```sql 148 | create materialized view users_view as 149 | with t as ( 150 | select *, row_number() over(partition by uuid order by inserted_at desc) as row_number 151 | from events 152 | where type = 'user_update' 153 | ) 154 | select uuid, body->>'name' as name, inserted_at from t where row_number = 1; 155 | 156 | select * from users_view; 157 | ``` 158 | In this case we assume that the most recent update event contains the correct user data, and we query to find the most recent `update_user` event for each user identified. 159 | -------------------------------------------------------------------------------- /data.sql: -------------------------------------------------------------------------------- 1 | drop table if exists "users"; 2 | 3 | CREATE TABLE "users" ( 4 | "id" serial primary key not null, 5 | "uuid" uuid NOT NULL, 6 | "name" text NOT NULL, 7 | "inserted_at" timestamp(6) NOT NULL DEFAULT 'NOW()', 8 | "updated_at" timestamp(6) NOT NULL DEFAULT 'NOW()' 9 | ); 10 | 11 | CREATE UNIQUE INDEX "users_uuid_index" ON "users" USING btree(uuid); 12 | 13 | insert into events (type, uuid, body) 14 | values ('user_create', '11111111-1111-1111-1111-111111111111', '{"name": "blah"}'); 15 | 16 | insert into events (type, uuid, body) 17 | values ('user_update', '11111111-1111-1111-1111-111111111111', '{"name": "vtha"}'); 18 | 19 | 20 | -- Retrigger events 21 | do language plpgsql $$ 22 | declare 23 | e record; 24 | begin 25 | for e in select uuid, body from events where type = 'user_create' order by inserted_at asc loop 26 | perform fn_project_user_create(e.uuid, e.body); 27 | end loop; 28 | end; 29 | $$; 30 | 31 | 32 | truncate table users; 33 | do language plpgsql $$ 34 | declare 35 | e record; 36 | begin 37 | for e in select type, uuid, body from events where uuid = '11111111-1111-1111-1111-111111111111' order by inserted_at asc loop 38 | if e.type = 'user_create' then 39 | perform fn_project_user_create(e.uuid, e.body); 40 | end if; 41 | if e.type = 'user_update' then 42 | perform fn_project_user_update(e.uuid, e.body); 43 | end if; 44 | end loop; 45 | end; 46 | $$; 47 | 48 | 49 | drop materialized view if exists "users_view"; 50 | 51 | create materialized view users_view as 52 | with t as ( 53 | select *, row_number() over(partition by uuid order by inserted_at desc) as row_number 54 | from events 55 | where type = 'update_user' 56 | ) 57 | select uuid, body->>'name' as name, inserted_at from t where row_number = 1; 58 | 59 | select * from users_view; 60 | -------------------------------------------------------------------------------- /functions.sql: -------------------------------------------------------------------------------- 1 | 2 | drop function if exists fn_project_user_insert(uuid uuid, body jsonb); 3 | create or replace function fn_project_user_create(uuid uuid, body jsonb) returns integer as $$ 4 | declare result int; 5 | begin 6 | insert into users(uuid, name, inserted_at, updated_at) 7 | values(uuid, body->>'name', NOW(), NOW()) 8 | returning id into result; 9 | return result; 10 | end; 11 | $$ language plpgsql security definer; 12 | 13 | drop function if exists fn_project_user_update(uuid uuid, body jsonb); 14 | create or replace function fn_project_user_update(uuid uuid, body jsonb) returns void as $$ 15 | begin 16 | update users SET name = body->>'name', updated_at = NOW() 17 | where users.uuid = fn_project_user_update.uuid; 18 | end; 19 | $$ language plpgsql security definer; 20 | -------------------------------------------------------------------------------- /immutable.sql: -------------------------------------------------------------------------------- 1 | create or replace function fn_trigger_reject_update_or_delete() returns trigger as $$ 2 | begin 3 | RETURN NULL; 4 | end; 5 | $$ language plpgsql security definer; 6 | 7 | drop trigger if exists event_reject_update_or_delete ON events; 8 | create trigger event_reject_update_or_delete before update or delete on events 9 | for each row 10 | execute procedure fn_trigger_reject_update_or_delete(); 11 | -------------------------------------------------------------------------------- /scratch.sql: -------------------------------------------------------------------------------- 1 | 2 | insert into events (type, uuid, body) 3 | values ('create_user', '11111111-1111-1111-1111-111111111111', '{"name": "blah"}'); 4 | 5 | 6 | insert into events (type, uuid, body) 7 | values ('update_user', '11111111-1111-1111-1111-111111111111', '{"name": "vtha"}'); 8 | 9 | 10 | insert into events (type, uuid, body) 11 | values ('update_user', '11111111-1111-1111-1111-111111111111', '{"name": "toby"}'); 12 | 13 | 14 | 15 | SELECT * 16 | FROM events e 17 | WHERE inserted_at = ( 18 | SELECT MAX(e2.inserted_at) 19 | FROM events e2 20 | WHERE e2.uuid = e.uuid 21 | ) 22 | 23 | 24 | create or replace function fn_event_insert() returns trigger 25 | security definer 26 | language plpgsql 27 | as $$ 28 | begin 29 | if new.body ?& array['blah'] then 30 | insert into users(id, name, inserted_at, updated_at) 31 | values(new.id, new.body->>'blah', NOW(), NOW()) 32 | on conflict (id) do 33 | update SET name = new.body->>'blah', updated_at = NOW() 34 | where users.id = new.id; 35 | end if; 36 | return new; 37 | end; 38 | $$; 39 | 40 | create or replace function fn_event_insert_action(event jsonb) returns integer 41 | security definer 42 | language plpgsql 43 | as $$ 44 | declare return_id int; 45 | begin 46 | insert into users(id, name, inserted_at, updated_at) 47 | values((event->>'id')::int, event->>'name', NOW(), NOW()) 48 | RETURNING id into return_id; 49 | return return_id; 50 | end; 51 | $$; 52 | 53 | 54 | SELECT fn_event_insert_action(body) FROM events LIMIT 1; 55 | -------------------------------------------------------------------------------- /structure.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS "events"; 2 | 3 | CREATE TABLE "events" ( 4 | "id" serial primary key not null, 5 | "uuid" uuid NOT NULL, 6 | "type" text NOT NULL, 7 | "body" jsonb NOT NULL, 8 | "inserted_at" timestamp(6) NOT NULL DEFAULT statement_timestamp() 9 | ); 10 | 11 | CREATE INDEX "idx_events_type" ON "events" (type ASC); 12 | 13 | CREATE INDEX "idx_events_uuid" ON "events" (uuid); 14 | 15 | CREATE INDEX "idx_events_inserted_at" ON "events" (inserted_at DESC); 16 | -------------------------------------------------------------------------------- /trigger.sql: -------------------------------------------------------------------------------- 1 | 2 | create or replace function fn_trigger_user_create() returns trigger 3 | security definer 4 | language plpgsql 5 | as $$ 6 | begin 7 | perform fn_project_user_create(new.uuid, new.body); 8 | return new; 9 | end; 10 | $$; 11 | 12 | create or replace function fn_trigger_user_update() returns trigger 13 | security definer 14 | language plpgsql 15 | as $$ 16 | begin 17 | perform fn_project_user_update(new.uuid, new.body); 18 | return new; 19 | end; 20 | $$; 21 | 22 | drop trigger if exists event_insert_user_create ON events; 23 | create trigger event_insert_user_create after insert on events 24 | for each row 25 | when (new.type = 'user_create') 26 | execute procedure fn_trigger_user_create(); 27 | 28 | drop trigger if exists event_insert_user_update ON events; 29 | create trigger event_insert_user_update after insert on events 30 | for each row 31 | when (new.type = 'user_update') 32 | execute procedure fn_trigger_user_update(); 33 | --------------------------------------------------------------------------------