Files
vt-fe/docs/ABAC_Database_Schema.md
2025-11-06 11:45:59 +01:00

14 KiB

ABAC (Attribute-Based Access Control) Database Schema

Overview

ABAC is a flexible access control model that makes authorization decisions based on attributes of:

  • Subject (User): who is requesting access
  • Resource (Object): what is being accessed
  • Action: what operation is being performed
  • Environment: contextual information (time, location, etc.)

Core Database Tables

1. Users Table

Stores user information and their attributes.

CREATE TABLE users (
    id SERIAL PRIMARY KEY,
    username VARCHAR(255) UNIQUE NOT NULL,
    email VARCHAR(255) UNIQUE NOT NULL,
    department VARCHAR(100),
    role VARCHAR(100),
    security_clearance VARCHAR(50),
    employee_level INT,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

2. User Attributes Table

Flexible key-value storage for dynamic user attributes.

CREATE TABLE user_attributes (
    id SERIAL PRIMARY KEY,
    user_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    attribute_key VARCHAR(100) NOT NULL,
    attribute_value TEXT NOT NULL,
    attribute_type VARCHAR(50) DEFAULT 'string', -- string, number, boolean, json
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(user_id, attribute_key)
);

CREATE INDEX idx_user_attributes_user_id ON user_attributes(user_id);
CREATE INDEX idx_user_attributes_key ON user_attributes(attribute_key);

3. Resources Table

Stores resources (projects, documents, etc.) and their attributes.

CREATE TABLE resources (
    id SERIAL PRIMARY KEY,
    resource_type VARCHAR(100) NOT NULL, -- 'project', 'document', 'crm_contact', etc.
    resource_id VARCHAR(255) NOT NULL, -- ID of the actual resource
    owner_id INT REFERENCES users(id),
    classification VARCHAR(50), -- 'public', 'internal', 'confidential', 'secret'
    department VARCHAR(100),
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(resource_type, resource_id)
);

CREATE INDEX idx_resources_type_id ON resources(resource_type, resource_id);
CREATE INDEX idx_resources_owner ON resources(owner_id);

4. Resource Attributes Table

Flexible key-value storage for dynamic resource attributes.

CREATE TABLE resource_attributes (
    id SERIAL PRIMARY KEY,
    resource_id INT NOT NULL REFERENCES resources(id) ON DELETE CASCADE,
    attribute_key VARCHAR(100) NOT NULL,
    attribute_value TEXT NOT NULL,
    attribute_type VARCHAR(50) DEFAULT 'string',
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(resource_id, attribute_key)
);

CREATE INDEX idx_resource_attributes_resource_id ON resource_attributes(resource_id);
CREATE INDEX idx_resource_attributes_key ON resource_attributes(attribute_key);

5. Policies Table

Stores ABAC policies that define access rules.

CREATE TABLE policies (
    id SERIAL PRIMARY KEY,
    name VARCHAR(255) NOT NULL,
    description TEXT,
    effect VARCHAR(10) NOT NULL CHECK (effect IN ('allow', 'deny')),
    priority INT DEFAULT 0, -- Higher priority policies are evaluated first
    enabled BOOLEAN DEFAULT true,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE INDEX idx_policies_enabled ON policies(enabled);
CREATE INDEX idx_policies_priority ON policies(priority DESC);

6. Policy Rules Table

Defines the conditions for each policy.

CREATE TABLE policy_rules (
    id SERIAL PRIMARY KEY,
    policy_id INT NOT NULL REFERENCES policies(id) ON DELETE CASCADE,
    rule_type VARCHAR(50) NOT NULL, -- 'subject', 'resource', 'action', 'environment'
    attribute_key VARCHAR(100) NOT NULL,
    operator VARCHAR(50) NOT NULL, -- 'equals', 'not_equals', 'contains', 'in', 'greater_than', 'less_than', 'matches_regex'
    attribute_value TEXT NOT NULL,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE INDEX idx_policy_rules_policy_id ON policy_rules(policy_id);
CREATE INDEX idx_policy_rules_type ON policy_rules(rule_type);

7. Policy Actions Table

Defines which actions a policy applies to.

CREATE TABLE policy_actions (
    id SERIAL PRIMARY KEY,
    policy_id INT NOT NULL REFERENCES policies(id) ON DELETE CASCADE,
    action VARCHAR(100) NOT NULL, -- 'read', 'write', 'delete', 'execute', 'approve', etc.
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(policy_id, action)
);

CREATE INDEX idx_policy_actions_policy_id ON policy_actions(policy_id);

8. Environment Attributes Table

Stores contextual/environment attributes for policies.

CREATE TABLE environment_attributes (
    id SERIAL PRIMARY KEY,
    attribute_key VARCHAR(100) NOT NULL,
    attribute_value TEXT NOT NULL,
    attribute_type VARCHAR(50) DEFAULT 'string',
    description TEXT,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(attribute_key)
);

9. Access Logs Table

Audit trail for access decisions.

CREATE TABLE access_logs (
    id SERIAL PRIMARY KEY,
    user_id INT REFERENCES users(id),
    resource_type VARCHAR(100),
    resource_id VARCHAR(255),
    action VARCHAR(100),
    decision VARCHAR(10), -- 'allow', 'deny'
    policy_id INT REFERENCES policies(id),
    reason TEXT,
    ip_address INET,
    user_agent TEXT,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE INDEX idx_access_logs_user_id ON access_logs(user_id);
CREATE INDEX idx_access_logs_resource ON access_logs(resource_type, resource_id);
CREATE INDEX idx_access_logs_created_at ON access_logs(created_at);

Example Data for Your Application

Example 1: Department-Based Access to Projects

-- Policy: Allow users to read projects in their department
INSERT INTO policies (name, description, effect, priority) 
VALUES ('Department Project Read Access', 'Users can read projects in their department', 'allow', 100);

-- Subject rule: User must be in a department
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (1, 'subject', 'department', 'equals', '${resource.department}');

-- Resource rule: Resource must be a project
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (1, 'resource', 'resource_type', 'equals', 'project');

-- Action: Read
INSERT INTO policy_actions (policy_id, action)
VALUES (1, 'read');

Example 2: Role-Based Access with Clearance Level

-- Policy: Allow managers to edit projects with clearance level <= their level
INSERT INTO policies (name, description, effect, priority)
VALUES ('Manager Project Edit Access', 'Managers can edit projects within their clearance', 'allow', 90);

-- Subject rule: User must be a manager
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (2, 'subject', 'role', 'equals', 'manager');

-- Subject rule: User clearance must be >= resource clearance
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (2, 'subject', 'security_clearance', 'greater_than_or_equal', '${resource.classification_level}');

-- Resource rule: Resource must be a project
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (2, 'resource', 'resource_type', 'equals', 'project');

-- Action: Write
INSERT INTO policy_actions (policy_id, action)
VALUES (2, 'write'), (2, 'update');

Example 3: Time-Based Access (Environment Attribute)

-- Policy: Allow access only during business hours
INSERT INTO policies (name, description, effect, priority)
VALUES ('Business Hours Access', 'Access allowed only during business hours', 'allow', 80);

-- Environment rule: Current time must be between 9 AM and 5 PM
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (3, 'environment', 'current_hour', 'between', '9,17');

-- Environment rule: Current day must be weekday
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (3, 'environment', 'day_of_week', 'in', 'Monday,Tuesday,Wednesday,Thursday,Friday');

Example 4: Owner-Based Access

-- Policy: Resource owners have full access
INSERT INTO policies (name, description, effect, priority)
VALUES ('Owner Full Access', 'Resource owners have full access to their resources', 'allow', 200);

-- Subject rule: User ID must match resource owner ID
INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES (4, 'subject', 'user_id', 'equals', '${resource.owner_id}');

-- Actions: All
INSERT INTO policy_actions (policy_id, action)
VALUES (4, 'read'), (4, 'write'), (4, 'delete'), (4, 'share');

Integration with Your Existing Schema

Extending Your Project Table

-- Add ABAC resource reference to your existing projekt table
ALTER TABLE projekt ADD COLUMN resource_id INT REFERENCES resources(id);

-- Create trigger to automatically create resource entry
CREATE OR REPLACE FUNCTION create_project_resource()
RETURNS TRIGGER AS $$
BEGIN
    INSERT INTO resources (resource_type, resource_id, owner_id, classification, department)
    VALUES ('project', NEW.id::VARCHAR, NEW.created_by, 'internal', NEW.department)
    RETURNING id INTO NEW.resource_id;
    RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER project_resource_trigger
BEFORE INSERT ON projekt
FOR EACH ROW
EXECUTE FUNCTION create_project_resource();

Policy Evaluation Algorithm

The typical flow for evaluating ABAC policies:

  1. Collect Attributes

    • Subject attributes (from user and user_attributes tables)
    • Resource attributes (from resources and resource_attributes tables)
    • Action being performed
    • Environment attributes (time, IP, location, etc.)
  2. Fetch Applicable Policies

    • Get all enabled policies
    • Filter by action
    • Order by priority (descending)
  3. Evaluate Each Policy

    • Check if all policy rules match
    • Use operators to compare attribute values
    • Support variable substitution (e.g., ${resource.owner_id})
  4. Make Decision

    • If any "deny" policy matches → DENY
    • If any "allow" policy matches → ALLOW
    • If no policies match → DENY (default deny)
  5. Log Decision

    • Record in access_logs table

Example Query: Check Access

-- Function to check if user has access to a resource
CREATE OR REPLACE FUNCTION check_access(
    p_user_id INT,
    p_resource_type VARCHAR,
    p_resource_id VARCHAR,
    p_action VARCHAR
) RETURNS BOOLEAN AS $$
DECLARE
    v_has_access BOOLEAN := FALSE;
    v_policy RECORD;
    v_rules_match BOOLEAN;
BEGIN
    -- Get user attributes
    -- Get resource attributes
    -- Get environment attributes
    
    -- Loop through policies ordered by priority
    FOR v_policy IN 
        SELECT p.* 
        FROM policies p
        INNER JOIN policy_actions pa ON p.id = pa.policy_id
        WHERE p.enabled = true 
        AND pa.action = p_action
        ORDER BY p.priority DESC
    LOOP
        -- Check if all rules match
        v_rules_match := evaluate_policy_rules(v_policy.id, p_user_id, p_resource_type, p_resource_id);
        
        IF v_rules_match THEN
            IF v_policy.effect = 'deny' THEN
                RETURN FALSE; -- Explicit deny
            ELSE
                v_has_access := TRUE;
            END IF;
        END IF;
    END LOOP;
    
    RETURN v_has_access;
END;
$$ LANGUAGE plpgsql;

Performance Considerations

  1. Indexing: Ensure proper indexes on frequently queried columns
  2. Caching: Cache policy evaluations for frequently accessed resources
  3. Materialized Views: For complex attribute queries
  4. Denormalization: Consider storing computed attributes for faster access
  5. Policy Compilation: Pre-compile policies into optimized decision trees

Advantages of ABAC

  1. Flexibility: Easy to add new attributes without schema changes
  2. Fine-grained Control: Policies can be very specific
  3. Dynamic: Policies can reference runtime attributes
  4. Scalable: Policies are independent of users and resources
  5. Auditable: Clear policy definitions and access logs

Migration Path from RBAC to ABAC

If you currently use Role-Based Access Control (RBAC), you can gradually migrate:

  1. Keep existing roles as user attributes
  2. Create policies that check role attributes
  3. Gradually add more attribute-based rules
  4. Eventually phase out simple role checks

Example for Your Application

-- Sample data for your project management system

-- User with attributes
INSERT INTO users (id, username, email, department, role, security_clearance, employee_level)
VALUES (1, 'john.doe', 'john@example.com', 'Engineering', 'senior_developer', 'confidential', 3);

INSERT INTO user_attributes (user_id, attribute_key, attribute_value, attribute_type)
VALUES 
    (1, 'can_approve_budgets', 'true', 'boolean'),
    (1, 'max_budget_approval', '50000', 'number'),
    (1, 'project_types', '["web", "mobile", "api"]', 'json');

-- Project as resource
INSERT INTO resources (resource_type, resource_id, owner_id, classification, department)
VALUES ('project', '123', 1, 'internal', 'Engineering');

INSERT INTO resource_attributes (resource_id, attribute_key, attribute_value, attribute_type)
VALUES
    (1, 'budget', '30000', 'number'),
    (1, 'status', 'active', 'string'),
    (1, 'project_type', 'web', 'string');

-- Policy: Senior developers can edit active projects in their department
INSERT INTO policies (name, description, effect, priority)
VALUES ('Senior Dev Project Edit', 'Senior developers can edit active projects', 'allow', 100);

INSERT INTO policy_rules (policy_id, rule_type, attribute_key, operator, attribute_value)
VALUES
    (5, 'subject', 'role', 'equals', 'senior_developer'),
    (5, 'subject', 'department', 'equals', '${resource.department}'),
    (5, 'resource', 'resource_type', 'equals', 'project'),
    (5, 'resource', 'status', 'equals', 'active');

INSERT INTO policy_actions (policy_id, action)
VALUES (5, 'write'), (5, 'update');

Conclusion

This ABAC schema provides:

  • Flexible attribute-based access control
  • Clear separation of concerns
  • Audit trail
  • Easy policy management
  • Scalability for complex authorization requirements

You can implement this alongside your existing authentication system and gradually migrate your authorization logic to use ABAC policies.