-- 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, type 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) ); -- 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, type TEXT NOT NULL, created_at BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL, created_by TEXT DEFAULT 'system' NOT NULL ); -- 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); -- 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();