meti-backend/migrations/000001_init_db.up.sql
Aditya Siregar 9e95e8ee5e Init Eslogad
2025-08-09 15:09:43 +07:00

146 lines
5.5 KiB
PL/PgSQL

-- ESLOGAD Core Init (Users, Roles, Permissions, Departments, Positions)
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
CREATE EXTENSION IF NOT EXISTS ltree;
-- Helper to auto-update updated_at
CREATE OR REPLACE FUNCTION set_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =======================
-- USERS
-- =======================
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
username VARCHAR(100) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
name VARCHAR(255),
email VARCHAR(255) UNIQUE,
status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active','inactive')),
is_active BOOLEAN NOT NULL DEFAULT TRUE,
last_login_at TIMESTAMP WITHOUT TIME ZONE,
created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
CREATE TRIGGER trg_users_updated_at
BEFORE UPDATE ON users
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- =======================
-- ROLES & PERMISSIONS
-- =======================
CREATE TABLE IF NOT EXISTS roles (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL, -- e.g., SUPERADMIN
code TEXT UNIQUE NOT NULL, -- e.g., superadmin
description TEXT,
created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER trg_roles_updated_at
BEFORE UPDATE ON roles
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS permissions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
code TEXT UNIQUE NOT NULL, -- e.g., letter.view
description TEXT,
created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER trg_permissions_updated_at
BEFORE UPDATE ON permissions
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS user_role (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
assigned_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
removed_at TIMESTAMP WITHOUT TIME ZONE
)
;
CREATE UNIQUE INDEX IF NOT EXISTS uq_user_role_active
ON user_role(user_id, role_id) WHERE removed_at IS NULL;
CREATE TABLE IF NOT EXISTS role_permissions (
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE,
PRIMARY KEY (role_id, permission_id)
);
CREATE TABLE IF NOT EXISTS departments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL,
code TEXT UNIQUE,
path LTREE UNIQUE NOT NULL, -- e.g., eslogad.aslog.waaslog_faskon_bmn
created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_departments_path_gist
ON departments USING GIST (path);
CREATE TRIGGER trg_departments_updated_at
BEFORE UPDATE ON departments
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS positions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL, -- e.g., PABAN III/FASKON
code TEXT UNIQUE, -- e.g., paban-III-faskon
path LTREE UNIQUE NOT NULL, -- hierarchy within org chart
created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_positions_path_gist
ON positions USING GIST (path);
CREATE TRIGGER trg_positions_updated_at
BEFORE UPDATE ON positions
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS user_department (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
department_id UUID NOT NULL REFERENCES departments(id) ON DELETE CASCADE,
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
assigned_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
removed_at TIMESTAMP WITHOUT TIME ZONE
);
CREATE UNIQUE INDEX IF NOT EXISTS uq_user_department_active
ON user_department(user_id, department_id) WHERE removed_at IS NULL;
CREATE TRIGGER trg_user_department_updated_at
BEFORE UPDATE ON user_department
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS user_position (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
position_id UUID NOT NULL REFERENCES positions(id) ON DELETE CASCADE,
assigned_at TIMESTAMP WITHOUT TIME ZONE DEFAULT CURRENT_TIMESTAMP,
removed_at TIMESTAMP WITHOUT TIME ZONE
);
CREATE UNIQUE INDEX IF NOT EXISTS uq_user_position_active
ON user_position(user_id, position_id) WHERE removed_at IS NULL;
CREATE TRIGGER trg_user_position_updated_at
BEFORE UPDATE ON user_position
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE IF NOT EXISTS position_roles (
position_id UUID NOT NULL REFERENCES positions(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
PRIMARY KEY (position_id, role_id)
);