-- RBAC System Migration for PostgreSQL -- Migration: 003_rbac_system -- Database: PostgreSQL -- User categories table CREATE TABLE IF NOT EXISTS user_categories ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) NOT NULL UNIQUE, description TEXT, parent_id UUID REFERENCES user_categories(id) ON DELETE CASCADE, metadata JSONB, is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- User tags table CREATE TABLE IF NOT EXISTS user_tags ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) NOT NULL UNIQUE, description TEXT, color VARCHAR(7), -- hex color code metadata JSONB, is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- User category assignments CREATE TABLE IF NOT EXISTS user_category_assignments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, category_id UUID NOT NULL REFERENCES user_categories(id) ON DELETE CASCADE, assigned_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), assigned_by UUID REFERENCES users(id), expires_at TIMESTAMPTZ, UNIQUE(user_id, category_id) ); -- User tag assignments CREATE TABLE IF NOT EXISTS user_tag_assignments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, tag_id UUID NOT NULL REFERENCES user_tags(id) ON DELETE CASCADE, assigned_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), assigned_by UUID REFERENCES users(id), expires_at TIMESTAMPTZ, UNIQUE(user_id, tag_id) ); -- Access rules table CREATE TABLE IF NOT EXISTS access_rules ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(255) NOT NULL, description TEXT, resource_type VARCHAR(50) NOT NULL, -- 'database', 'file', 'directory', 'content', 'api' resource_name VARCHAR(500) NOT NULL, -- supports wildcards action VARCHAR(50) NOT NULL, -- 'read', 'write', 'delete', 'execute' priority INTEGER NOT NULL DEFAULT 0, -- higher priority rules evaluated first is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Role requirements for access rules CREATE TABLE IF NOT EXISTS access_rule_roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), rule_id UUID NOT NULL REFERENCES access_rules(id) ON DELETE CASCADE, role_id UUID NOT NULL REFERENCES user_roles(id) ON DELETE CASCADE, UNIQUE(rule_id, role_id) ); -- Permission requirements for access rules CREATE TABLE IF NOT EXISTS access_rule_permissions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), rule_id UUID NOT NULL REFERENCES access_rules(id) ON DELETE CASCADE, permission_name VARCHAR(100) NOT NULL, resource_scope VARCHAR(255), -- optional scope for permission UNIQUE(rule_id, permission_name, resource_scope) ); -- Category requirements for access rules CREATE TABLE IF NOT EXISTS access_rule_categories ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), rule_id UUID NOT NULL REFERENCES access_rules(id) ON DELETE CASCADE, category_id UUID NOT NULL REFERENCES user_categories(id) ON DELETE CASCADE, requirement_type VARCHAR(20) NOT NULL DEFAULT 'required', -- 'required', 'denied' UNIQUE(rule_id, category_id, requirement_type) ); -- Tag requirements for access rules CREATE TABLE IF NOT EXISTS access_rule_tags ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), rule_id UUID NOT NULL REFERENCES access_rules(id) ON DELETE CASCADE, tag_id UUID NOT NULL REFERENCES user_tags(id) ON DELETE CASCADE, requirement_type VARCHAR(20) NOT NULL DEFAULT 'required', -- 'required', 'denied' UNIQUE(rule_id, tag_id, requirement_type) ); -- Permission cache for performance CREATE TABLE IF NOT EXISTS user_permission_cache ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, resource_type VARCHAR(50) NOT NULL, resource_name VARCHAR(500) NOT NULL, action VARCHAR(50) NOT NULL, access_result VARCHAR(20) NOT NULL, -- 'allow', 'deny', 'require_additional_auth' cache_key VARCHAR(255) NOT NULL, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, cache_key) ); -- RBAC configuration table for storing TOML configs CREATE TABLE IF NOT EXISTS rbac_configs ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) NOT NULL UNIQUE, description TEXT, config_data JSONB NOT NULL, is_active BOOLEAN NOT NULL DEFAULT true, version INTEGER NOT NULL DEFAULT 1, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Audit log for access attempts CREATE TABLE IF NOT EXISTS access_audit_log ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, resource_type VARCHAR(50) NOT NULL, resource_name VARCHAR(500) NOT NULL, action VARCHAR(50) NOT NULL, access_result VARCHAR(20) NOT NULL, rule_id UUID REFERENCES access_rules(id) ON DELETE SET NULL, ip_address INET, user_agent TEXT, session_id VARCHAR(255), additional_context JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create indexes for performance CREATE INDEX IF NOT EXISTS idx_user_categories_name ON user_categories(name); CREATE INDEX IF NOT EXISTS idx_user_categories_parent ON user_categories(parent_id); CREATE INDEX IF NOT EXISTS idx_user_categories_active ON user_categories(is_active); CREATE INDEX IF NOT EXISTS idx_user_tags_name ON user_tags(name); CREATE INDEX IF NOT EXISTS idx_user_tags_active ON user_tags(is_active); CREATE INDEX IF NOT EXISTS idx_user_category_assignments_user ON user_category_assignments(user_id); CREATE INDEX IF NOT EXISTS idx_user_category_assignments_category ON user_category_assignments(category_id); CREATE INDEX IF NOT EXISTS idx_user_category_assignments_expires ON user_category_assignments(expires_at); CREATE INDEX IF NOT EXISTS idx_user_tag_assignments_user ON user_tag_assignments(user_id); CREATE INDEX IF NOT EXISTS idx_user_tag_assignments_tag ON user_tag_assignments(tag_id); CREATE INDEX IF NOT EXISTS idx_user_tag_assignments_expires ON user_tag_assignments(expires_at); CREATE INDEX IF NOT EXISTS idx_access_rules_resource ON access_rules(resource_type, resource_name); CREATE INDEX IF NOT EXISTS idx_access_rules_action ON access_rules(action); CREATE INDEX IF NOT EXISTS idx_access_rules_priority ON access_rules(priority DESC); CREATE INDEX IF NOT EXISTS idx_access_rules_active ON access_rules(is_active); CREATE INDEX IF NOT EXISTS idx_access_rule_roles_rule ON access_rule_roles(rule_id); CREATE INDEX IF NOT EXISTS idx_access_rule_roles_role ON access_rule_roles(role_id); CREATE INDEX IF NOT EXISTS idx_access_rule_permissions_rule ON access_rule_permissions(rule_id); CREATE INDEX IF NOT EXISTS idx_access_rule_permissions_name ON access_rule_permissions(permission_name); CREATE INDEX IF NOT EXISTS idx_access_rule_categories_rule ON access_rule_categories(rule_id); CREATE INDEX IF NOT EXISTS idx_access_rule_categories_category ON access_rule_categories(category_id); CREATE INDEX IF NOT EXISTS idx_access_rule_tags_rule ON access_rule_tags(rule_id); CREATE INDEX IF NOT EXISTS idx_access_rule_tags_tag ON access_rule_tags(tag_id); CREATE INDEX IF NOT EXISTS idx_user_permission_cache_user ON user_permission_cache(user_id); CREATE INDEX IF NOT EXISTS idx_user_permission_cache_key ON user_permission_cache(cache_key); CREATE INDEX IF NOT EXISTS idx_user_permission_cache_expires ON user_permission_cache(expires_at); CREATE INDEX IF NOT EXISTS idx_rbac_configs_name ON rbac_configs(name); CREATE INDEX IF NOT EXISTS idx_rbac_configs_active ON rbac_configs(is_active); CREATE INDEX IF NOT EXISTS idx_access_audit_log_user ON access_audit_log(user_id); CREATE INDEX IF NOT EXISTS idx_access_audit_log_resource ON access_audit_log(resource_type, resource_name); CREATE INDEX IF NOT EXISTS idx_access_audit_log_created ON access_audit_log(created_at); -- Add triggers for updated_at columns CREATE TRIGGER update_user_categories_updated_at BEFORE UPDATE ON user_categories FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_user_tags_updated_at BEFORE UPDATE ON user_tags FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_access_rules_updated_at BEFORE UPDATE ON access_rules FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_rbac_configs_updated_at BEFORE UPDATE ON rbac_configs FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Function to clean up expired permission cache CREATE OR REPLACE FUNCTION cleanup_expired_permission_cache() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER; BEGIN DELETE FROM user_permission_cache WHERE expires_at < NOW(); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END; $$ LANGUAGE plpgsql; -- Function to get user categories (including inherited) CREATE OR REPLACE FUNCTION get_user_categories(user_uuid UUID) RETURNS TABLE(category_name VARCHAR(100)) AS $$ BEGIN RETURN QUERY WITH RECURSIVE category_tree AS ( -- Direct categories SELECT uc.name, uc.parent_id FROM user_categories uc JOIN user_category_assignments uca ON uc.id = uca.category_id WHERE uca.user_id = user_uuid AND uc.is_active = true AND (uca.expires_at IS NULL OR uca.expires_at > NOW()) UNION ALL -- Parent categories SELECT uc.name, uc.parent_id FROM user_categories uc JOIN category_tree ct ON uc.id = ct.parent_id WHERE uc.is_active = true ) SELECT DISTINCT ct.name FROM category_tree ct; END; $$ LANGUAGE plpgsql; -- Function to get user tags CREATE OR REPLACE FUNCTION get_user_tags(user_uuid UUID) RETURNS TABLE(tag_name VARCHAR(100)) AS $$ BEGIN RETURN QUERY SELECT ut.name FROM user_tags ut JOIN user_tag_assignments uta ON ut.id = uta.tag_id WHERE uta.user_id = user_uuid AND ut.is_active = true AND (uta.expires_at IS NULL OR uta.expires_at > NOW()); END; $$ LANGUAGE plpgsql; -- Insert default categories INSERT INTO user_categories (name, description) VALUES ('admin', 'Administrative access category'), ('editor', 'Content editing access category'), ('viewer', 'Read-only access category'), ('finance', 'Financial data access category'), ('hr', 'Human resources access category'), ('it', 'Information technology access category') ON CONFLICT (name) DO NOTHING; -- Insert default tags INSERT INTO user_tags (name, description, color) VALUES ('sensitive', 'Access to sensitive data', '#ff0000'), ('public', 'Public data access', '#00ff00'), ('internal', 'Internal data access', '#ffff00'), ('confidential', 'Confidential data access', '#ff8800'), ('restricted', 'Restricted access', '#8800ff'), ('temporary', 'Temporary access', '#00ffff') ON CONFLICT (name) DO NOTHING; -- Insert default RBAC configuration INSERT INTO rbac_configs (name, description, config_data) VALUES ('default', 'Default RBAC configuration', '{ "rules": [ { "id": "admin_full_access", "resource_type": "Database", "resource_name": "*", "allowed_roles": ["Admin"], "allowed_permissions": [], "required_categories": [], "required_tags": [], "deny_categories": [], "deny_tags": [], "is_active": true }, { "id": "editor_content_access", "resource_type": "Database", "resource_name": "content*", "allowed_roles": ["Editor"], "allowed_permissions": ["WriteContent"], "required_categories": ["editor"], "required_tags": [], "deny_categories": [], "deny_tags": ["restricted"], "is_active": true } ], "default_permissions": { "Database": ["ReadContent"], "File": ["ReadFile"] }, "category_hierarchies": { "admin": ["editor", "viewer"], "editor": ["viewer"] }, "tag_hierarchies": { "public": ["internal"], "internal": ["confidential"], "confidential": ["restricted"] }, "cache_ttl_seconds": 300 }') ON CONFLICT (name) DO NOTHING;