| 
 | 1 | +-- Main etcd table for key-value storage with revision history  | 
 | 2 | +CREATE TABLE etcd (  | 
 | 3 | +ts timestamp with time zone NOT NULL DEFAULT now(),  | 
 | 4 | +key text NOT NULL,  | 
 | 5 | +value text,  | 
 | 6 | +revision bigint NOT NULL,  | 
 | 7 | +tombstone boolean NOT NULL DEFAULT false,  | 
 | 8 | +PRIMARY KEY(key, revision)  | 
 | 9 | +);  | 
 | 10 | + | 
 | 11 | +-- Write-ahead log table for tracking changes to be synchronized  | 
 | 12 | +CREATE TABLE etcd_wal (  | 
 | 13 | +ts timestamp with time zone NOT NULL DEFAULT now(),  | 
 | 14 | +key text NOT NULL,  | 
 | 15 | +value text,  | 
 | 16 | +revision bigint, -- Current revision before modification (null = new key)  | 
 | 17 | +PRIMARY KEY(key, ts)  | 
 | 18 | +);  | 
 | 19 | + | 
 | 20 | +-- Performance indexes  | 
 | 21 | +CREATE INDEX idx_etcd_key_revision ON etcd(key, revision DESC);  | 
 | 22 | +CREATE INDEX idx_etcd_wal_key ON etcd_wal(key);  | 
 | 23 | +CREATE INDEX idx_etcd_wal_ts ON etcd_wal(ts);  | 
 | 24 | + | 
 | 25 | +-- Function: Get latest value for a key with revision enforcement  | 
 | 26 | +CREATE OR REPLACE FUNCTION etcd_get(p_key text)  | 
 | 27 | +RETURNS TABLE(key text, value text, revision bigint, tombstone boolean, ts timestamp with time zone)  | 
 | 28 | +LANGUAGE sql STABLE AS $$  | 
 | 29 | +SELECT e.key, e.value, e.revision, e.tombstone, e.ts  | 
 | 30 | +FROM etcd e  | 
 | 31 | +WHERE e.key = p_key  | 
 | 32 | +ORDER BY e.revision DESC  | 
 | 33 | +LIMIT 1;  | 
 | 34 | +$$;  | 
 | 35 | + | 
 | 36 | +-- Function: Get all revisions for a key higher than passed revision  | 
 | 37 | +CREATE OR REPLACE FUNCTION etcd_get_all(p_key text, p_min_revision bigint DEFAULT 0)  | 
 | 38 | +RETURNS TABLE(key text, value text, revision bigint, tombstone boolean, ts timestamp with time zone)  | 
 | 39 | +LANGUAGE sql STABLE AS $$  | 
 | 40 | +SELECT e.key, e.value, e.revision, e.tombstone, e.ts  | 
 | 41 | +FROM etcd e  | 
 | 42 | +WHERE e.key = p_key AND e.revision > p_min_revision  | 
 | 43 | +ORDER BY e.revision ASC;  | 
 | 44 | +$$;  | 
 | 45 | + | 
 | 46 | +-- Function: Set key-value (logs to WAL for synchronization to etcd)  | 
 | 47 | +CREATE OR REPLACE FUNCTION etcd_set(p_key text, p_value text)  | 
 | 48 | +RETURNS timestamp with time zone  | 
 | 49 | +LANGUAGE sql AS $$  | 
 | 50 | +INSERT INTO etcd_wal (key, value, revision)  | 
 | 51 | +SELECT p_key, p_value, (SELECT revision FROM etcd_get(p_key))  | 
 | 52 | +RETURNING ts;  | 
 | 53 | +$$;  | 
 | 54 | + | 
 | 55 | +-- Function: Delete key (logs to WAL for synchronization to etcd)  | 
 | 56 | +CREATE OR REPLACE FUNCTION etcd_delete(p_key text)  | 
 | 57 | +RETURNS timestamp with time zone  | 
 | 58 | +LANGUAGE sql AS $$  | 
 | 59 | +INSERT INTO etcd_wal (key, value, revision)  | 
 | 60 | +SELECT p_key, NULL, (SELECT revision FROM etcd_get(p_key))  | 
 | 61 | +RETURNING ts;  | 
 | 62 | +$$;  | 
 | 63 | + | 
 | 64 | +-- Trigger function to notify on WAL changes  | 
 | 65 | +CREATE OR REPLACE FUNCTION notify_etcd_change()  | 
 | 66 | +RETURNS TRIGGER AS $$  | 
 | 67 | +BEGIN  | 
 | 68 | +PERFORM pg_notify('etcd_changes',   | 
 | 69 | +json_build_object(  | 
 | 70 | +'key', NEW.key,  | 
 | 71 | +'ts', NEW.ts,  | 
 | 72 | +'value', NEW.value,  | 
 | 73 | +'revision', NEW.revision,  | 
 | 74 | +'operation', CASE   | 
 | 75 | +WHEN NEW.value IS NULL THEN 'DELETE'  | 
 | 76 | +WHEN NEW.revision IS NULL THEN 'CREATE'  | 
 | 77 | +ELSE 'UPDATE'  | 
 | 78 | +END  | 
 | 79 | +)::text  | 
 | 80 | +);  | 
 | 81 | +RETURN NEW;  | 
 | 82 | +END;  | 
 | 83 | +$$ LANGUAGE plpgsql;  | 
 | 84 | + | 
 | 85 | +-- Trigger on WAL table for real-time notifications  | 
 | 86 | +CREATE TRIGGER etcd_wal_notify  | 
 | 87 | +AFTER INSERT ON etcd_wal  | 
 | 88 | +FOR EACH ROW  | 
 | 89 | +EXECUTE FUNCTION notify_etcd_change();  | 
0 commit comments