-- PostgreSQL schema for schedule-management-system (RBAC + core domain) -- Requires: CREATE EXTENSION IF NOT EXISTS "pgcrypto"; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; CREATE TABLE roles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, external_role_id TEXT UNIQUE, description TEXT, is_system BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE permissions ( code TEXT PRIMARY KEY, name TEXT NOT NULL, module TEXT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE role_permissions ( role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE, permission_code TEXT NOT NULL REFERENCES permissions(code) ON DELETE CASCADE, PRIMARY KEY (role_id, permission_code) ); CREATE TABLE campuses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, external_hosp_id TEXT UNIQUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE departments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), campus_id UUID NOT NULL REFERENCES campuses(id) ON DELETE RESTRICT, name TEXT NOT NULL, external_dept_id TEXT UNIQUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE sync_states ( key TEXT PRIMARY KEY, token TEXT NOT NULL, last_sync_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, account TEXT NOT NULL UNIQUE, phone TEXT, title TEXT, avatar TEXT, external_user_id TEXT, tenant_id TEXT, tenant_name TEXT, hosp_id TEXT, hosp_name TEXT, role_id UUID NOT NULL REFERENCES roles(id) ON DELETE RESTRICT, campus_id UUID REFERENCES campuses(id) ON DELETE SET NULL, dept_id UUID REFERENCES departments(id) ON DELETE SET NULL, status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive')), password_hash TEXT NOT NULL, token_version INTEGER NOT NULL DEFAULT 1, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE shifts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, start_time TIME NOT NULL, end_time TIME NOT NULL, enabled BOOLEAN NOT NULL DEFAULT TRUE, remark TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE schedule_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), dept_id UUID NOT NULL REFERENCES departments(id) ON DELETE RESTRICT, date DATE NOT NULL, shift_id UUID REFERENCES shifts(id) ON DELETE RESTRICT, staff_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, tag TEXT NOT NULL DEFAULT 'normal' CHECK (tag IN ('normal', 'substitute', 'substituted', 'stopClinic')), note TEXT, original_staff_id UUID REFERENCES users(id) ON DELETE SET NULL, substitute_for_id UUID REFERENCES schedule_items(id) ON DELETE SET NULL, reason TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (dept_id, date, shift_id, staff_id) ); CREATE INDEX schedule_items_dept_date_idx ON schedule_items (dept_id, date); CREATE INDEX schedule_items_staff_date_idx ON schedule_items (staff_id, date); CREATE TABLE duty_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), date DATE NOT NULL, staff_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, duty_type TEXT NOT NULL CHECK (duty_type IN ('day', 'night', '24h')), contact TEXT, note TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX duty_items_date_idx ON duty_items (date); CREATE TABLE adjust_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), dept_id UUID NOT NULL REFERENCES departments(id) ON DELETE RESTRICT, date DATE NOT NULL, type TEXT NOT NULL CHECK (type IN ('swap', 'stopClinic', 'substitute')), operator TEXT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), note TEXT ); CREATE TABLE audit_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), actor_id UUID REFERENCES users(id) ON DELETE SET NULL, action TEXT NOT NULL, target_type TEXT NOT NULL, target_id UUID, detail JSONB, ip TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() );