-- Migration 002: Authentication & Authorization System -- Based on OmniSync auth implementation -- Users table CREATE TABLE IF NOT EXISTS users ( user_id SERIAL PRIMARY KEY, username VARCHAR(100) UNIQUE NOT NULL, email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, full_name VARCHAR(255), is_active BOOLEAN DEFAULT TRUE, is_superadmin BOOLEAN DEFAULT FALSE, failed_login_attempts INTEGER DEFAULT 0, locked_until TIMESTAMP, last_login_at TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Groups table CREATE TABLE IF NOT EXISTS groups ( id SERIAL PRIMARY KEY, name VARCHAR(100) UNIQUE NOT NULL, description TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Permissions table CREATE TABLE IF NOT EXISTS permissions ( id SERIAL PRIMARY KEY, code VARCHAR(100) UNIQUE NOT NULL, description TEXT, category VARCHAR(50), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- User-Group relationship CREATE TABLE IF NOT EXISTS user_groups ( user_id INTEGER REFERENCES users(user_id) ON DELETE CASCADE, group_id INTEGER REFERENCES groups(id) ON DELETE CASCADE, assigned_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (user_id, group_id) ); -- Group-Permission relationship CREATE TABLE IF NOT EXISTS group_permissions ( group_id INTEGER REFERENCES groups(id) ON DELETE CASCADE, permission_id INTEGER REFERENCES permissions(id) ON DELETE CASCADE, PRIMARY KEY (group_id, permission_id) ); -- Sessions table (for JWT token revocation) CREATE TABLE IF NOT EXISTS sessions ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(user_id) ON DELETE CASCADE, token_jti VARCHAR(255) UNIQUE NOT NULL, expires_at TIMESTAMP NOT NULL, revoked BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Audit log table CREATE TABLE IF NOT EXISTS audit_log ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(user_id) ON DELETE SET NULL, username VARCHAR(100), action VARCHAR(100) NOT NULL, resource_type VARCHAR(100), resource_id INTEGER, resource_name VARCHAR(255), before_value TEXT, after_value TEXT, success BOOLEAN DEFAULT TRUE, error_message TEXT, ip_address VARCHAR(45), user_agent TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_users_username ON users(username); CREATE INDEX IF NOT EXISTS idx_users_email ON users(email); CREATE INDEX IF NOT EXISTS idx_sessions_jti ON sessions(token_jti); CREATE INDEX IF NOT EXISTS idx_sessions_user ON sessions(user_id); CREATE INDEX IF NOT EXISTS idx_audit_user ON audit_log(user_id); CREATE INDEX IF NOT EXISTS idx_audit_action ON audit_log(action); CREATE INDEX IF NOT EXISTS idx_audit_created ON audit_log(created_at); -- Insert default permissions INSERT INTO permissions (code, description, category) VALUES -- Customers ('customers.view', 'View customers', 'customers'), ('customers.edit', 'Edit customers', 'customers'), ('customers.create', 'Create customers', 'customers'), ('customers.delete', 'Delete customers', 'customers'), -- Hardware ('hardware.view', 'View hardware', 'hardware'), ('hardware.edit', 'Edit hardware', 'hardware'), ('hardware.create', 'Create hardware', 'hardware'), ('hardware.delete', 'Delete hardware', 'hardware'), ('hardware.assign', 'Assign hardware to customers', 'hardware'), -- Billing ('billing.view', 'View billing information', 'billing'), ('billing.edit', 'Edit billing information', 'billing'), ('billing.approve', 'Approve billing items', 'billing'), -- System ('system.view', 'View system settings', 'system'), ('system.edit', 'Edit system settings', 'system'), -- Reports ('reports.view', 'View reports', 'reports'), ('reports.export', 'Export reports', 'reports'), -- Audit ('audit.view', 'View audit logs', 'audit'), -- Admin ('users.manage', 'Manage users and groups', 'admin'), ('permissions.manage', 'Manage permissions', 'admin'), ('system.admin', 'Full system administration', 'admin') ON CONFLICT (code) DO NOTHING; -- Insert default groups INSERT INTO groups (name, description) VALUES ('Administrators', 'Full system access'), ('Managers', 'Can manage customers and billing'), ('Technicians', 'Can manage hardware and assignments'), ('Viewers', 'Read-only access') ON CONFLICT (name) DO NOTHING; -- Assign permissions to Administrators group (all permissions) INSERT INTO group_permissions (group_id, permission_id) SELECT g.id, p.id FROM groups g CROSS JOIN permissions p WHERE g.name = 'Administrators' ON CONFLICT DO NOTHING; -- Assign permissions to Managers group INSERT INTO group_permissions (group_id, permission_id) SELECT g.id, p.id FROM groups g CROSS JOIN permissions p WHERE g.name = 'Managers' AND p.code IN ( 'customers.view', 'customers.edit', 'customers.create', 'hardware.view', 'billing.view', 'billing.edit', 'billing.approve', 'reports.view', 'reports.export' ) ON CONFLICT DO NOTHING; -- Assign permissions to Technicians group INSERT INTO group_permissions (group_id, permission_id) SELECT g.id, p.id FROM groups g CROSS JOIN permissions p WHERE g.name = 'Technicians' AND p.code IN ( 'customers.view', 'hardware.view', 'hardware.edit', 'hardware.create', 'hardware.assign', 'reports.view' ) ON CONFLICT DO NOTHING; -- Assign permissions to Viewers group INSERT INTO group_permissions (group_id, permission_id) SELECT g.id, p.id FROM groups g CROSS JOIN permissions p WHERE g.name = 'Viewers' AND p.code IN ( 'customers.view', 'hardware.view', 'billing.view', 'reports.view' ) ON CONFLICT DO NOTHING; -- Create default admin user (password: admin123, hashed with SHA256) -- SHA256 hash of 'admin123' INSERT INTO users (username, email, password_hash, full_name, is_superadmin, is_active) VALUES ( 'admin', 'admin@bmcnetworks.dk', '240be518fabd2724ddb6f04eeb1da5967448d7e831c08c8fa822809f74c720a9', 'System Administrator', TRUE, TRUE ) ON CONFLICT (username) DO NOTHING; -- Assign admin user to Administrators group INSERT INTO user_groups (user_id, group_id) SELECT u.user_id, g.id FROM users u CROSS JOIN groups g WHERE u.username = 'admin' AND g.name = 'Administrators' ON CONFLICT DO NOTHING; -- Update timestamp trigger function CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; -- Add trigger to users table DROP TRIGGER IF EXISTS update_users_updated_at ON users; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();