# c77_rbac Tutorial - Part 2: Building the TechCorp Database **Tutorial Navigation:** - [Part 1: Getting Started](TUTORIAL-Part1.md) - Prerequisites and installation - **Part 2: Building the TechCorp Database** (this document) - Creating the schema and data - [Part 3: Implementing RBAC](TUTORIAL-Part3.md) - Setting up roles and permissions - [Part 4: Row-Level Security](TUTORIAL-Part4.md) - Applying access controls - [Part 5: Testing and Validation](TUTORIAL-Part5.md) - Security testing - [Part 6: Advanced Features](TUTORIAL-Part6.md) - Bulk operations and monitoring --- ### Prerequisites Make sure you're connected as the `techcorp_app` user created in Part 1: ```bash # If not already connected as techcorp_app: psql -d techcorp_tutorial -U techcorp_app -W ``` ## Chapter 2: Creating the TechCorp Database Schema Now we'll create a realistic multi-department company database that will demonstrate all aspects of the c77_rbac system. ### Step 1: Create Core Tables ```sql -- Create departments table CREATE TABLE departments ( id SERIAL PRIMARY KEY, name TEXT UNIQUE NOT NULL, code TEXT UNIQUE NOT NULL, description TEXT, budget DECIMAL(12,2), manager_id INTEGER, -- Will reference users table created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create users table (represents our application users) CREATE TABLE users ( id SERIAL PRIMARY KEY, email TEXT UNIQUE NOT NULL, first_name TEXT NOT NULL, last_name TEXT NOT NULL, department_id INTEGER REFERENCES departments(id), employee_type TEXT NOT NULL DEFAULT 'employee', -- 'employee', 'contractor', 'manager', 'admin' hire_date DATE DEFAULT CURRENT_DATE, salary DECIMAL(10,2), is_active BOOLEAN DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Add foreign key constraint for department manager ALTER TABLE departments ADD CONSTRAINT fk_dept_manager FOREIGN KEY (manager_id) REFERENCES users(id); -- Create projects table CREATE TABLE projects ( id SERIAL PRIMARY KEY, name TEXT NOT NULL, description TEXT, department_id INTEGER REFERENCES departments(id), project_manager_id INTEGER REFERENCES users(id), status TEXT DEFAULT 'planning', -- 'planning', 'active', 'on_hold', 'completed', 'cancelled' budget DECIMAL(12,2), start_date DATE, end_date DATE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create project team members CREATE TABLE project_members ( id SERIAL PRIMARY KEY, project_id INTEGER REFERENCES projects(id), user_id INTEGER REFERENCES users(id), role TEXT DEFAULT 'member', -- 'member', 'lead', 'observer' added_date DATE DEFAULT CURRENT_DATE, UNIQUE(project_id, user_id) ); -- Create documents table CREATE TABLE documents ( id SERIAL PRIMARY KEY, title TEXT NOT NULL, content TEXT, file_path TEXT, author_id INTEGER REFERENCES users(id), department_id INTEGER REFERENCES departments(id), project_id INTEGER REFERENCES projects(id) NULL, security_level TEXT DEFAULT 'internal', -- 'public', 'internal', 'confidential', 'restricted' status TEXT DEFAULT 'draft', -- 'draft', 'published', 'archived' created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create expenses table CREATE TABLE expenses ( id SERIAL PRIMARY KEY, description TEXT NOT NULL, amount DECIMAL(10,2) NOT NULL, category TEXT NOT NULL, -- 'travel', 'equipment', 'software', 'training', 'other' submitted_by INTEGER REFERENCES users(id), department_id INTEGER REFERENCES departments(id), project_id INTEGER REFERENCES projects(id) NULL, status TEXT DEFAULT 'submitted', -- 'submitted', 'approved', 'rejected', 'paid' submitted_date DATE DEFAULT CURRENT_DATE, approved_by INTEGER REFERENCES users(id) NULL, approved_date DATE NULL, notes TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create audit log for sensitive operations CREATE TABLE audit_log ( id BIGSERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id), action TEXT NOT NULL, table_name TEXT, record_id INTEGER, old_values JSONB, new_values JSONB, ip_address INET, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` ### Step 2: Insert Sample Data ```sql -- Insert departments INSERT INTO departments (name, code, description, budget) VALUES ('Engineering', 'ENG', 'Software development and infrastructure', 2500000.00), ('Sales', 'SALES', 'Customer acquisition and revenue generation', 1800000.00), ('Human Resources', 'HR', 'Employee management and company culture', 800000.00), ('Finance', 'FIN', 'Financial planning and accounting', 600000.00), ('Marketing', 'MKT', 'Brand management and lead generation', 1200000.00); -- Insert users (these IDs will be our external_ids in RBAC) INSERT INTO users (id, email, first_name, last_name, department_id, employee_type, salary) VALUES -- Engineering Department (1, 'alice.admin@techcorp.com', 'Alice', 'Admin', 1, 'admin', 150000.00), (101, 'bob.engineer@techcorp.com', 'Bob', 'Smith', 1, 'manager', 120000.00), (102, 'carol.dev@techcorp.com', 'Carol', 'Johnson', 1, 'employee', 95000.00), (103, 'dave.senior@techcorp.com', 'Dave', 'Wilson', 1, 'employee', 110000.00), (104, 'eve.contractor@techcorp.com', 'Eve', 'Brown', 1, 'contractor', 85000.00), -- Sales Department (201, 'frank.sales@techcorp.com', 'Frank', 'Davis', 2, 'manager', 130000.00), (202, 'grace.rep@techcorp.com', 'Grace', 'Miller', 2, 'employee', 75000.00), (203, 'henry.rep@techcorp.com', 'Henry', 'Garcia', 2, 'employee', 72000.00), -- HR Department (301, 'iris.hr@techcorp.com', 'Iris', 'Martinez', 3, 'manager', 105000.00), (302, 'jack.hr@techcorp.com', 'Jack', 'Anderson', 3, 'employee', 68000.00), -- Finance Department (401, 'kelly.finance@techcorp.com', 'Kelly', 'Taylor', 4, 'manager', 115000.00), (402, 'liam.accounting@techcorp.com', 'Liam', 'Thomas', 4, 'employee', 65000.00), -- Marketing Department (501, 'maya.marketing@techcorp.com', 'Maya', 'White', 5, 'manager', 100000.00), (502, 'noah.content@techcorp.com', 'Noah', 'Harris', 5, 'employee', 70000.00); -- Update department managers UPDATE departments SET manager_id = 101 WHERE code = 'ENG'; UPDATE departments SET manager_id = 201 WHERE code = 'SALES'; UPDATE departments SET manager_id = 301 WHERE code = 'HR'; UPDATE departments SET manager_id = 401 WHERE code = 'FIN'; UPDATE departments SET manager_id = 501 WHERE code = 'MKT'; -- Insert sample projects INSERT INTO projects (name, description, department_id, project_manager_id, status, budget, start_date) VALUES ('Customer Portal V2', 'Rebuild customer-facing portal with modern tech stack', 1, 101, 'active', 500000.00, '2024-01-15'), ('Mobile App Development', 'Native mobile app for iOS and Android', 1, 103, 'planning', 300000.00, '2024-03-01'), ('Q1 Sales Campaign', 'Major sales push for Q1 targets', 2, 201, 'active', 150000.00, '2024-01-01'), ('Employee Onboarding System', 'Streamline new hire processes', 3, 301, 'planning', 75000.00, '2024-02-15'), ('Financial Reporting Dashboard', 'Real-time financial analytics', 4, 401, 'active', 120000.00, '2024-01-20'); -- Insert project team members INSERT INTO project_members (project_id, user_id, role) VALUES -- Customer Portal V2 team (1, 101, 'lead'), (1, 102, 'member'), (1, 103, 'member'), (1, 104, 'member'), -- Mobile App team (2, 103, 'lead'), (2, 102, 'member'), -- Sales Campaign team (3, 201, 'lead'), (3, 202, 'member'), (3, 203, 'member'), (3, 502, 'member'), -- Marketing support -- HR System team (4, 301, 'lead'), (4, 302, 'member'), (4, 102, 'member'), -- Engineering support -- Finance Dashboard team (5, 401, 'lead'), (5, 402, 'member'), (5, 103, 'member'); -- Engineering support -- Insert sample documents INSERT INTO documents (title, content, author_id, department_id, project_id, security_level, status) VALUES ('Company Handbook', 'Complete employee handbook with policies and procedures', 301, 3, NULL, 'internal', 'published'), ('Salary Ranges 2024', 'Confidential salary band information', 301, 3, NULL, 'confidential', 'published'), ('Customer Portal Requirements', 'Technical requirements for portal rebuild', 101, 1, 1, 'internal', 'published'), ('Sales Strategy Q1', 'Confidential sales strategy and targets', 201, 2, 3, 'confidential', 'published'), ('Security Policies', 'Company-wide security guidelines', 1, 1, NULL, 'internal', 'published'), ('Financial Results Q4', 'Quarterly financial performance', 401, 4, NULL, 'restricted', 'published'), ('Engineering Standards', 'Code review and development standards', 101, 1, NULL, 'internal', 'published'), ('Project Meeting Notes', 'Weekly standup meeting notes', 102, 1, 1, 'internal', 'draft'); -- Insert sample expenses INSERT INTO expenses (description, amount, category, submitted_by, department_id, project_id, status, notes) VALUES ('MacBook Pro for development', 2499.00, 'equipment', 102, 1, 1, 'approved', 'For Customer Portal project'), ('Conference attendance - DevCon', 1200.00, 'training', 103, 1, NULL, 'submitted', 'Professional development'), ('Software licenses - IntelliJ', 500.00, 'software', 101, 1, NULL, 'approved', 'Team development tools'), ('Client dinner - ABC Corp', 350.00, 'travel', 201, 2, 3, 'approved', 'Q1 sales campaign'), ('Recruitment platform subscription', 800.00, 'software', 301, 3, NULL, 'submitted', 'Hiring tools'), ('Accounting software upgrade', 1500.00, 'software', 401, 4, NULL, 'submitted', 'Financial reporting needs'), ('Team building event', 2000.00, 'other', 501, 5, NULL, 'approved', 'Department morale activity'); ``` ### Step 3: Add More Realistic Data ```sql -- Add more employees for testing bulk operations later INSERT INTO users (id, email, first_name, last_name, department_id, employee_type, salary) SELECT 1000 + generate_series, 'user' || generate_series || '@techcorp.com', 'User', 'Number' || generate_series, (generate_series % 5) + 1, -- Distribute across departments 'employee', 50000 + (generate_series % 50) * 1000 FROM generate_series(1, 50); -- Add more documents with varying security levels INSERT INTO documents (title, content, author_id, department_id, security_level, status) VALUES ('Public Company Blog Post', 'Public facing marketing content', 502, 5, 'public', 'published'), ('Internal Newsletter Q1', 'Quarterly company updates for all employees', 301, 3, 'internal', 'published'), ('HR Policy Updates', 'Confidential updates to employee policies', 301, 3, 'confidential', 'published'), ('Executive Compensation Plan', 'Restricted financial information', 401, 4, 'restricted', 'published'), ('Engineering Roadmap 2024', 'Technical strategy and roadmap', 101, 1, 'confidential', 'published'), ('Sales Territory Assignments', 'Confidential sales territory information', 201, 2, 'confidential', 'published'), ('Marketing Budget Breakdown', 'Detailed marketing spend analysis', 501, 5, 'confidential', 'draft'); -- Add more expenses for comprehensive testing INSERT INTO expenses (description, amount, category, submitted_by, department_id, status, notes) VALUES ('Sales team laptops', 8500.00, 'equipment', 201, 2, 'approved', 'Quarterly equipment refresh'), ('HR software license', 3600.00, 'software', 301, 3, 'submitted', 'Annual subscription renewal'), ('Marketing campaign costs', 15000.00, 'other', 501, 5, 'approved', 'Q1 digital advertising'), ('Training workshop', 2800.00, 'training', 102, 1, 'submitted', 'React development workshop'), ('Office supplies', 450.00, 'other', 302, 3, 'approved', 'Monthly office supply order'), ('Travel expenses - client visit', 1250.00, 'travel', 202, 2, 'submitted', 'San Francisco client meeting'); ``` **✅ Checkpoint 2:** You now have a complete company database with realistic data! ### Step 4: Verify Your Data ```sql -- Check department structure SELECT d.name as department, d.code, m.first_name || ' ' || m.last_name as manager, count(u.id) as total_employees, d.budget FROM departments d LEFT JOIN users m ON d.manager_id = m.id LEFT JOIN users u ON d.id = u.department_id GROUP BY d.id, d.name, d.code, m.first_name, m.last_name, d.budget ORDER BY d.name; -- Check project teams SELECT p.name as project, d.name as department, pm_user.first_name || ' ' || pm_user.last_name as project_manager, count(pms.user_id) as team_size, p.budget, p.status FROM projects p JOIN departments d ON p.department_id = d.id JOIN users pm_user ON p.project_manager_id = pm_user.id LEFT JOIN project_members pms ON p.id = pms.project_id GROUP BY p.id, p.name, d.name, pm_user.first_name, pm_user.last_name, p.budget, p.status ORDER BY p.name; -- Check document security levels SELECT security_level, count(*) as document_count, round(count(*) * 100.0 / sum(count(*)) OVER (), 1) as percentage FROM documents GROUP BY security_level ORDER BY count(*) DESC; -- Check user distribution SELECT d.name as department, d.code, count(u.id) as user_count, count(CASE WHEN u.employee_type = 'manager' THEN 1 END) as managers, count(CASE WHEN u.employee_type = 'employee' THEN 1 END) as employees, count(CASE WHEN u.employee_type = 'contractor' THEN 1 END) as contractors FROM departments d LEFT JOIN users u ON d.id = u.department_id GROUP BY d.id, d.name, d.code ORDER BY d.name; ``` --- ## What's Next? Now that we have a complete company database with realistic data, in **Part 3** we'll implement the RBAC system: - Define company-wide features and permissions - Create role hierarchies (Admin, Manager, Employee, Contractor) - Assign users to appropriate roles with proper scoping - Set up department-based and project-based access patterns **Continue to [Part 3: Implementing RBAC](TUTORIAL-Part3.md)** --- ## Database Summary You've created a comprehensive TechCorp database with: ### Core Tables - **5 departments** with realistic budgets and managers - **65+ users** across different roles and departments - **5 projects** with cross-departmental teams - **15+ documents** with varying security levels - **13+ expense records** with different approval states - **Audit logging** capabilities ### Key Features - **Realistic relationships** between departments, users, and projects - **Multiple security levels** for documents (public, internal, confidential, restricted) - **Cross-departmental collaboration** through project teams - **Comprehensive expense tracking** with approval workflows - **Audit trail** for sensitive operations This database will serve as the foundation for demonstrating all aspects of the c77_rbac system in the following parts of the tutorial.