CREATE EXTENSION IF NOT EXISTS pg_trgm; CREATE EXTENSION IF NOT EXISTS pgcrypto; CREATE SEQUENCE node_updates; CREATE TABLE public."user" ( id serial4 NOT NULL, username varchar NOT NULL, "name" varchar NOT NULL, "password" varchar NOT NULL, last_login timestamp DEFAULT now() NOT NULL, timezone varchar DEFAULT 'UTC'::character varying NOT NULL, CONSTRAINT user_pk PRIMARY KEY (id) ); CREATE TABLE public.node ( id serial4 NOT NULL, user_id int4 NOT NULL, "uuid" bpchar(36) DEFAULT gen_random_uuid() NOT NULL, parent_uuid bpchar(36) NULL, created timestamptz DEFAULT NOW() NOT NULL, updated timestamptz DEFAULT NOW() NOT NULL, deleted timestamptz NULL, created_seq bigint NOT NULL DEFAULT nextval('node_updates'), updated_seq bigint NOT NULL DEFAULT nextval('node_updates'), deleted_seq bigint NULL, "name" varchar(256) DEFAULT ''::character varying NOT NULL, "content" text DEFAULT ''::text NOT NULL, content_encrypted text DEFAULT ''::text NOT NULL, markdown bool DEFAULT false NOT NULL, CONSTRAINT name_length CHECK ((length(TRIM(BOTH FROM name)) > 0)), CONSTRAINT node_pk PRIMARY KEY (id), CONSTRAINT user_fk FOREIGN KEY (user_id) REFERENCES public."user"(id) ON DELETE RESTRICT ON UPDATE RESTRICT ); CREATE UNIQUE INDEX node_uuid_idx ON public.node USING btree (uuid); CREATE INDEX node_search_index ON public.node USING gin (name gin_trgm_ops, content gin_trgm_ops); CREATE OR REPLACE FUNCTION node_update_timestamp() RETURNS TRIGGER LANGUAGE PLPGSQL AS $$ BEGIN IF NEW.updated = OLD.updated THEN UPDATE node SET updated = NOW(), updated_seq = nextval('node_updates') WHERE id=NEW.id; END IF; RETURN NEW; END; $$; CREATE OR REPLACE TRIGGER node_update AFTER UPDATE ON node FOR EACH ROW EXECUTE PROCEDURE node_update_timestamp();