-- PostgreSQL-specific schema with BIGINT UNIX timestamps -- Main content table (current versions only) CREATE TABLE content ( id TEXT NOT NULL, site_id TEXT NOT NULL, html_content TEXT NOT NULL, original_template TEXT, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, updated_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, last_edited_by TEXT DEFAULT 'system' NOT NULL, PRIMARY KEY (id, site_id) ); -- Version history table for rollback functionality CREATE TABLE content_versions ( version_id SERIAL PRIMARY KEY, content_id TEXT NOT NULL, site_id TEXT NOT NULL, html_content TEXT NOT NULL, original_template TEXT, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, created_by TEXT DEFAULT 'system' NOT NULL ); -- Collections table - manages .insertr-add containers CREATE TABLE collections ( id TEXT NOT NULL, site_id TEXT NOT NULL, container_html TEXT NOT NULL, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, updated_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, last_edited_by TEXT DEFAULT 'system' NOT NULL, PRIMARY KEY (id, site_id) ); -- Collection templates - multiple template variants per collection CREATE TABLE collection_templates ( template_id SERIAL PRIMARY KEY, collection_id TEXT NOT NULL, site_id TEXT NOT NULL, name TEXT NOT NULL, html_template TEXT NOT NULL, is_default BOOLEAN DEFAULT FALSE NOT NULL, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, FOREIGN KEY (collection_id, site_id) REFERENCES collections(id, site_id) ON DELETE CASCADE ); -- Collection items - individual items within collections CREATE TABLE collection_items ( item_id TEXT NOT NULL, collection_id TEXT NOT NULL, site_id TEXT NOT NULL, template_id INTEGER NOT NULL, html_content TEXT NOT NULL, position INTEGER NOT NULL, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, updated_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, last_edited_by TEXT DEFAULT 'system' NOT NULL, PRIMARY KEY (item_id, collection_id, site_id), FOREIGN KEY (collection_id, site_id) REFERENCES collections(id, site_id) ON DELETE CASCADE, FOREIGN KEY (template_id) REFERENCES collection_templates(template_id) ON DELETE RESTRICT ); -- Collection item version history CREATE TABLE collection_item_versions ( version_id SERIAL PRIMARY KEY, item_id TEXT NOT NULL, collection_id TEXT NOT NULL, site_id TEXT NOT NULL, html_content TEXT NOT NULL, template_id INTEGER NOT NULL, position INTEGER NOT NULL, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, created_by TEXT DEFAULT 'system' NOT NULL, FOREIGN KEY (item_id, collection_id, site_id) REFERENCES collection_items(item_id, collection_id, site_id) ON DELETE CASCADE ); -- Indexes for performance CREATE INDEX IF NOT EXISTS idx_content_site_id ON content(site_id); CREATE INDEX IF NOT EXISTS idx_content_updated_at ON content(updated_at); CREATE INDEX IF NOT EXISTS idx_content_versions_lookup ON content_versions(content_id, site_id, created_at DESC); -- Collection indexes for performance CREATE INDEX IF NOT EXISTS idx_collections_site_id ON collections(site_id); CREATE INDEX IF NOT EXISTS idx_collections_updated_at ON collections(updated_at); CREATE INDEX IF NOT EXISTS idx_collection_templates_lookup ON collection_templates(collection_id, site_id); CREATE INDEX IF NOT EXISTS idx_collection_templates_default ON collection_templates(collection_id, site_id, is_default DESC); CREATE INDEX IF NOT EXISTS idx_collection_items_lookup ON collection_items(collection_id, site_id, position); CREATE INDEX IF NOT EXISTS idx_collection_items_template ON collection_items(template_id); CREATE INDEX IF NOT EXISTS idx_collection_item_versions_lookup ON collection_item_versions(item_id, collection_id, site_id, created_at DESC); -- Constraint to ensure only one default template per collection CREATE UNIQUE INDEX IF NOT EXISTS idx_collection_templates_one_default ON collection_templates(collection_id, site_id) WHERE is_default = TRUE; -- Function and trigger to automatically update updated_at timestamp CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = EXTRACT(EPOCH FROM NOW()); RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_content_updated_at BEFORE UPDATE ON content FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Triggers for collection timestamps CREATE TRIGGER update_collections_updated_at BEFORE UPDATE ON collections FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_collection_items_updated_at BEFORE UPDATE ON collection_items FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();