-- ============================================ -- SCHEMA LOG - Sistema TZZR -- Log inmutable de mensajes -- ============================================ DROP SCHEMA IF EXISTS log CASCADE; CREATE SCHEMA log; -- Extensiones CREATE EXTENSION IF NOT EXISTS pgcrypto; -- Tipos CREATE TYPE log.actor_type AS ENUM ('user', 'agent', 'orchestrator', 'system', 'tool'); CREATE TYPE log.ref_type AS ENUM ('context', 'accountant', 'secretary'); -- ============================================ -- Tabla 1: messages -- ============================================ CREATE TABLE log.messages ( id BIGSERIAL PRIMARY KEY, hash CHAR(64) UNIQUE NOT NULL, session_hash CHAR(64) NOT NULL, thread_hash CHAR(64), sender_type log.actor_type NOT NULL, sender_id CHAR(64) NOT NULL, receiver_type log.actor_type NOT NULL, receiver_id CHAR(64) NOT NULL, leader_id CHAR(64), role TEXT, content TEXT NOT NULL, attachments JSONB DEFAULT '{}', prev_hash CHAR(64), hashtags CHAR(64)[] DEFAULT '{}', ambient JSONB, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX idx_messages_session ON log.messages(session_hash); CREATE INDEX idx_messages_thread ON log.messages(thread_hash); CREATE INDEX idx_messages_sender ON log.messages(sender_id); CREATE INDEX idx_messages_receiver ON log.messages(receiver_id); CREATE INDEX idx_messages_prev ON log.messages(prev_hash); CREATE INDEX idx_messages_created ON log.messages(created_at); CREATE INDEX idx_messages_hashtags ON log.messages USING gin(hashtags); -- ============================================ -- Tabla 2: message_refs -- Relaciona mensaje con contexto y conocimiento -- ============================================ CREATE TABLE log.message_refs ( id BIGSERIAL PRIMARY KEY, message_hash CHAR(64) NOT NULL, ref_hash CHAR(64) NOT NULL, ref_type log.ref_type NOT NULL, position INT NOT NULL, thread_hash CHAR(64), UNIQUE(message_hash, ref_hash) ); CREATE INDEX idx_refs_message ON log.message_refs(message_hash); CREATE INDEX idx_refs_ref ON log.message_refs(ref_hash); CREATE INDEX idx_refs_type ON log.message_refs(ref_type); CREATE INDEX idx_refs_thread ON log.message_refs(thread_hash); -- ============================================ -- Funciones -- ============================================ CREATE OR REPLACE FUNCTION log.sha256(data TEXT) RETURNS CHAR(64) AS $$ BEGIN RETURN encode(digest(data, 'sha256'), 'hex'); END; $$ LANGUAGE plpgsql IMMUTABLE; CREATE OR REPLACE FUNCTION log.prevent_update() RETURNS TRIGGER AS $$ BEGIN RAISE EXCEPTION 'UPDATE no permitido en %', TG_TABLE_NAME; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION log.prevent_delete() RETURNS TRIGGER AS $$ BEGIN RAISE EXCEPTION 'DELETE no permitido en %', TG_TABLE_NAME; END; $$ LANGUAGE plpgsql; -- ============================================ -- Triggers de protección -- ============================================ CREATE TRIGGER protect_messages_update BEFORE UPDATE ON log.messages FOR EACH ROW EXECUTE FUNCTION log.prevent_update(); CREATE TRIGGER protect_messages_delete BEFORE DELETE ON log.messages FOR EACH ROW EXECUTE FUNCTION log.prevent_delete(); CREATE TRIGGER protect_refs_update BEFORE UPDATE ON log.message_refs FOR EACH ROW EXECUTE FUNCTION log.prevent_update(); CREATE TRIGGER protect_refs_delete BEFORE DELETE ON log.message_refs FOR EACH ROW EXECUTE FUNCTION log.prevent_delete(); -- ============================================ -- Permisos -- ============================================ GRANT USAGE ON SCHEMA log TO tzzr; GRANT SELECT, INSERT ON log.messages TO tzzr; GRANT SELECT, INSERT ON log.message_refs TO tzzr; GRANT USAGE ON SEQUENCE log.messages_id_seq TO tzzr; GRANT USAGE ON SEQUENCE log.message_refs_id_seq TO tzzr; SELECT 'Schema log: 2 tablas creadas' as status;