BEGIN; -- ======================= -- SEQUENCE FOR LETTER NUMBER -- ======================= CREATE SEQUENCE IF NOT EXISTS letters_incoming_seq; -- ======================= -- LETTERS INCOMING -- ======================= CREATE TABLE IF NOT EXISTS letters_incoming ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_number TEXT NOT NULL UNIQUE DEFAULT ('IN-' || lpad(nextval('letters_incoming_seq')::text, 8, '0')), reference_number TEXT, subject TEXT NOT NULL, description TEXT, priority_id UUID REFERENCES priorities(id) ON DELETE SET NULL, sender_institution_id UUID REFERENCES institutions(id) ON DELETE SET NULL, received_date DATE NOT NULL, due_date DATE, status TEXT NOT NULL DEFAULT 'new' CHECK (status IN ('new','in_progress','completed')), created_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, deleted_at TIMESTAMP WITHOUT TIME ZONE ); CREATE INDEX IF NOT EXISTS idx_letters_incoming_status ON letters_incoming(status); CREATE INDEX IF NOT EXISTS idx_letters_incoming_received_date ON letters_incoming(received_date); CREATE TRIGGER trg_letters_incoming_updated_at BEFORE UPDATE ON letters_incoming FOR EACH ROW EXECUTE FUNCTION set_updated_at(); -- ======================= -- LETTER INCOMING RECIPIENTS -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_recipients ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, recipient_user_id UUID REFERENCES users(id) ON DELETE SET NULL, recipient_department_id UUID REFERENCES departments(id) ON DELETE SET NULL, status TEXT NOT NULL DEFAULT 'new' CHECK (status IN ('new','read','completed')), read_at TIMESTAMP WITHOUT TIME ZONE, completed_at TIMESTAMP WITHOUT TIME ZONE, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_recipients_letter ON letter_incoming_recipients(letter_id); -- ======================= -- LETTER INCOMING LABELS (M:N) -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_labels ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, label_id UUID NOT NULL REFERENCES labels(id) ON DELETE CASCADE, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, UNIQUE (letter_id, label_id) ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_labels_letter ON letter_incoming_labels(letter_id); -- ======================= -- LETTER INCOMING ATTACHMENTS -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_attachments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, file_url TEXT NOT NULL, file_name TEXT NOT NULL, file_type TEXT NOT NULL, uploaded_by UUID REFERENCES users(id) ON DELETE SET NULL, uploaded_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_attachments_letter ON letter_incoming_attachments(letter_id); -- ======================= -- LETTER DISPOSITIONS -- ======================= CREATE TABLE IF NOT EXISTS letter_dispositions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, from_user_id UUID REFERENCES users(id) ON DELETE SET NULL, from_department_id UUID REFERENCES departments(id) ON DELETE SET NULL, to_user_id UUID REFERENCES users(id) ON DELETE SET NULL, to_department_id UUID REFERENCES departments(id) ON DELETE SET NULL, notes TEXT, status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending','read','rejected','completed')), created_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, read_at TIMESTAMP WITHOUT TIME ZONE, completed_at TIMESTAMP WITHOUT TIME ZONE, updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_letter_dispositions_letter ON letter_dispositions(letter_id); CREATE TRIGGER trg_letter_dispositions_updated_at BEFORE UPDATE ON letter_dispositions FOR EACH ROW EXECUTE FUNCTION set_updated_at(); -- ======================= -- DISPOSITION NOTES -- ======================= CREATE TABLE IF NOT EXISTS disposition_notes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), disposition_id UUID NOT NULL REFERENCES letter_dispositions(id) ON DELETE CASCADE, user_id UUID REFERENCES users(id) ON DELETE SET NULL, note TEXT NOT NULL, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_disposition_notes_disposition ON disposition_notes(disposition_id); -- ======================= -- LETTER DISPOSITION ACTIONS (Selections) -- ======================= CREATE TABLE IF NOT EXISTS letter_disposition_actions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), disposition_id UUID NOT NULL REFERENCES letter_dispositions(id) ON DELETE CASCADE, action_id UUID NOT NULL REFERENCES disposition_actions(id) ON DELETE RESTRICT, note TEXT, created_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, UNIQUE (disposition_id, action_id) ); CREATE INDEX IF NOT EXISTS idx_letter_disposition_actions_disposition ON letter_disposition_actions(disposition_id); -- ======================= -- LETTER INCOMING DISCUSSIONS (Threaded) -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_discussions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, parent_id UUID REFERENCES letter_incoming_discussions(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, message TEXT NOT NULL, mentions JSONB, created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP, edited_at TIMESTAMP WITHOUT TIME ZONE ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_discussions_letter ON letter_incoming_discussions(letter_id); CREATE INDEX IF NOT EXISTS idx_letter_incoming_discussions_parent ON letter_incoming_discussions(parent_id); CREATE TRIGGER trg_letter_incoming_discussions_updated_at BEFORE UPDATE ON letter_incoming_discussions FOR EACH ROW EXECUTE FUNCTION set_updated_at(); -- ======================= -- LETTER INCOMING DISCUSSION ATTACHMENTS -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_discussion_attachments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), discussion_id UUID NOT NULL REFERENCES letter_incoming_discussions(id) ON DELETE CASCADE, file_url TEXT NOT NULL, file_name TEXT NOT NULL, file_type TEXT NOT NULL, uploaded_by UUID REFERENCES users(id) ON DELETE SET NULL, uploaded_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_discussion_attachments_discussion ON letter_incoming_discussion_attachments(discussion_id); -- ======================= -- LETTER INCOMING ACTIVITY LOGS (Immutable) -- ======================= CREATE TABLE IF NOT EXISTS letter_incoming_activity_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), letter_id UUID NOT NULL REFERENCES letters_incoming(id) ON DELETE CASCADE, action_type TEXT NOT NULL, actor_user_id UUID REFERENCES users(id) ON DELETE SET NULL, actor_department_id UUID REFERENCES departments(id) ON DELETE SET NULL, target_type TEXT, target_id UUID, from_status TEXT, to_status TEXT, context JSONB, occurred_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_letter_incoming_activity_logs_letter ON letter_incoming_activity_logs(letter_id); CREATE INDEX IF NOT EXISTS idx_letter_incoming_activity_logs_action ON letter_incoming_activity_logs(action_type); COMMIT;