c77_rbac/INSTALL.md
2025-05-23 23:29:45 -05:00

22 KiB

c77_rbac PostgreSQL Extension - Installation Guide

This comprehensive guide covers all aspects of installing and upgrading the c77_rbac extension, with detailed examples for different scenarios.

Table of Contents

  1. Prerequisites
  2. Installation Overview
  3. Fresh Installation (Version 1.1)
  4. Upgrading from Version 1.0
  5. Post-Installation Verification
  6. Initial Configuration
  7. Troubleshooting Installation Issues
  8. Uninstallation
  9. Production Deployment Checklist

Prerequisites

System Requirements

  • PostgreSQL: Version 14 or later
  • Operating System: Linux (Ubuntu, CentOS, RHEL, Debian), macOS, or Windows
  • Privileges: PostgreSQL superuser access for installation
  • Disk Space: Minimal (< 1MB for extension files)

Required Access Levels

  1. System Administrator: Access to copy files to PostgreSQL extension directory
  2. Database Superuser: To create the extension and grant privileges
  3. Application User: Regular database user for your application

Identify Your PostgreSQL Version and Paths

# Check PostgreSQL version
psql --version
# or
sudo -u postgres psql -c "SELECT version();"

# Find PostgreSQL installation directory
pg_config --sharedir
# Example output: /usr/share/postgresql/14

# Find extension directory
pg_config --sharedir
# Extension directory will be: /usr/share/postgresql/14/extension/

Installation Overview

File Structure

The c77_rbac extension consists of these files:

c77_rbac.control           # Extension metadata (version, dependencies)
c77_rbac--1.1.sql         # Fresh installation SQL script  
c77_rbac--1.0--1.1.sql    # Upgrade script (1.0 → 1.1)

Installation Paths

Choose the appropriate installation method:

  • Fresh Installation: Use c77_rbac--1.1.sql directly
  • Upgrade from 1.0: Use c77_rbac--1.0--1.1.sql upgrade script

Fresh Installation (Version 1.1)

Step 1: Download and Prepare Files

Download the extension files to a temporary directory:

# Create temporary directory
mkdir ~/c77_rbac_install
cd ~/c77_rbac_install

# Download files (replace with your actual download method)
wget https://github.com/yourusername/c77_rbac/releases/download/v1.1/c77_rbac.control
wget https://github.com/yourusername/c77_rbac/releases/download/v1.1/c77_rbac--1.1.sql

# Verify files downloaded
ls -la
# Should show:
# c77_rbac.control
# c77_rbac--1.1.sql

Step 2: Copy Files to PostgreSQL Extension Directory

For Ubuntu/Debian:

# Find the correct PostgreSQL version directory
PG_VERSION=$(pg_config --version | sed 's/PostgreSQL \([0-9]\+\).*/\1/')
echo "PostgreSQL version: $PG_VERSION"

# Copy files (requires sudo)
sudo cp c77_rbac.control /usr/share/postgresql/$PG_VERSION/extension/
sudo cp c77_rbac--1.1.sql /usr/share/postgresql/$PG_VERSION/extension/

# Verify files copied correctly
ls -la /usr/share/postgresql/$PG_VERSION/extension/c77_rbac*

For CentOS/RHEL/Rocky Linux:

# Find PostgreSQL version
PG_VERSION=$(pg_config --version | sed 's/PostgreSQL \([0-9]\+\).*/\1/')

# Copy files
sudo cp c77_rbac.control /usr/pgsql-$PG_VERSION/share/extension/
sudo cp c77_rbac--1.1.sql /usr/pgsql-$PG_VERSION/share/extension/

# Verify
ls -la /usr/pgsql-$PG_VERSION/share/extension/c77_rbac*

For macOS (with Homebrew):

# Find Homebrew PostgreSQL path
PG_CONFIG_PATH=$(which pg_config)
PG_SHARE_DIR=$(pg_config --sharedir)

# Copy files
sudo cp c77_rbac.control $PG_SHARE_DIR/extension/
sudo cp c77_rbac--1.1.sql $PG_SHARE_DIR/extension/

# Verify
ls -la $PG_SHARE_DIR/extension/c77_rbac*

Step 3: Create Database and Users

Connect as PostgreSQL superuser:

# Connect as postgres superuser
sudo -u postgres psql

Create your application database and users:

-- Create application database
CREATE DATABASE myapp_production;

-- Create application user with secure password
CREATE USER myapp_user WITH 
    PASSWORD 'your_very_secure_password_here'
    NOSUPERUSER 
    NOCREATEDB 
    NOCREATEROLE;

-- Optional: Create read-only user for reporting
CREATE USER myapp_readonly WITH 
    PASSWORD 'readonly_secure_password'
    NOSUPERUSER 
    NOCREATEDB 
    NOCREATEROLE;

-- List databases to verify
\l

Step 4: Install the Extension

Connect to your application database:

-- Connect to your database
\c myapp_production

Install the c77_rbac extension:

-- Install extension (this creates all tables, functions, views)
CREATE EXTENSION c77_rbac;

-- Verify installation
SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_rbac';
-- Should show: c77_rbac | 1.1

Step 5: Grant Privileges to Application User

Grant necessary privileges to your application user:

-- Grant database-level privileges
GRANT CONNECT ON DATABASE myapp_production TO myapp_user;
GRANT CREATE ON DATABASE myapp_production TO myapp_user;

-- Grant schema usage
GRANT USAGE ON SCHEMA public TO myapp_user;

-- Grant table privileges (read-only, modifications through functions)
GRANT SELECT ON ALL TABLES IN SCHEMA public TO myapp_user;
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO myapp_user;

-- Grant function execution privileges
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO myapp_user;

-- Set default privileges for future objects
ALTER DEFAULT PRIVILEGES IN SCHEMA public 
    GRANT SELECT ON TABLES TO myapp_user;

ALTER DEFAULT PRIVILEGES IN SCHEMA public 
    GRANT EXECUTE ON FUNCTIONS TO myapp_user;

ALTER DEFAULT PRIVILEGES IN SCHEMA public 
    GRANT USAGE, SELECT ON SEQUENCES TO myapp_user;

-- For readonly user (optional)
GRANT CONNECT ON DATABASE myapp_production TO myapp_readonly;
GRANT USAGE ON SCHEMA public TO myapp_readonly;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO myapp_readonly;
GRANT SELECT ON public.c77_rbac_user_permissions TO myapp_readonly;
GRANT SELECT ON public.c77_rbac_summary TO myapp_readonly;

Step 6: Verify Installation

Test the installation:

-- Check extension is installed
SELECT extname, extversion, extrelocatable FROM pg_extension WHERE extname = 'c77_rbac';

-- Check tables were created
\dt public.c77_rbac_*

-- Check functions were created
\df public.c77_rbac_*

-- Check views were created
\dv public.c77_rbac_*

-- Test basic functionality
SELECT public.c77_rbac_grant_feature('test_role', 'test_feature');
SELECT public.c77_rbac_assign_subject('test_user', 'test_role', 'global', 'all');
SELECT public.c77_rbac_can_access('test_feature', 'test_user', 'global', 'all');
-- Should return: true

-- Clean up test data
SELECT public.c77_rbac_revoke_subject_role('test_user', 'test_role', 'global', 'all');
SELECT public.c77_rbac_revoke_feature('test_role', 'test_feature');

Upgrading from Version 1.0

Pre-Upgrade Checklist

  1. Backup your database:

    pg_dump -U postgres -h localhost myapp_production > backup_before_upgrade.sql
    
  2. Verify current version:

    SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_rbac';
    -- Should show: c77_rbac | 1.0
    
  3. Check for dependencies:

    SELECT * FROM public.c77_rbac_show_dependencies();
    

Step 1: Download Upgrade Files

# Create upgrade directory
mkdir ~/c77_rbac_upgrade
cd ~/c77_rbac_upgrade

# Download upgrade files
wget https://github.com/yourusername/c77_rbac/releases/download/v1.1/c77_rbac.control
wget https://github.com/yourusername/c77_rbac/releases/download/v1.1/c77_rbac--1.0--1.1.sql

# Optional: Download full 1.1 script for reference
wget https://github.com/yourusername/c77_rbac/releases/download/v1.1/c77_rbac--1.1.sql

Step 2: Copy Upgrade Files

# Find PostgreSQL directory
PG_VERSION=$(pg_config --version | sed 's/PostgreSQL \([0-9]\+\).*/\1/')

# Copy files (Ubuntu/Debian)
sudo cp c77_rbac.control /usr/share/postgresql/$PG_VERSION/extension/
sudo cp c77_rbac--1.0--1.1.sql /usr/share/postgresql/$PG_VERSION/extension/

# For CentOS/RHEL, use:
# sudo cp c77_rbac.control /usr/pgsql-$PG_VERSION/share/extension/
# sudo cp c77_rbac--1.0--1.1.sql /usr/pgsql-$PG_VERSION/share/extension/

# Verify files
ls -la /usr/share/postgresql/$PG_VERSION/extension/c77_rbac*
# Should show:
# c77_rbac.control
# c77_rbac--1.0.sql (existing)
# c77_rbac--1.0--1.1.sql (new)

Step 3: Perform the Upgrade

Connect to your database as superuser:

sudo -u postgres psql -d myapp_production

Execute the upgrade:

-- Check current version
SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_rbac';

-- Perform upgrade
ALTER EXTENSION c77_rbac UPDATE TO '1.1';

-- Verify upgrade
SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_rbac';
-- Should now show: c77_rbac | 1.1

Step 4: Verify Upgrade Success

Test new functionality:

-- Test new bulk assignment function
SELECT * FROM public.c77_rbac_bulk_assign_subjects(
    ARRAY['user1', 'user2', 'user3'],
    'test_role',
    'department',
    'engineering'
);

-- Test new management views
SELECT * FROM public.c77_rbac_summary;

-- Test new utility functions
SELECT * FROM public.c77_rbac_get_user_roles('user1');

-- Test admin sync function
SELECT public.c77_rbac_sync_admin_features();

-- Clean up test data
SELECT public.c77_rbac_revoke_subject_role('user1', 'test_role', 'department', 'engineering');
SELECT public.c77_rbac_revoke_subject_role('user2', 'test_role', 'department', 'engineering');
SELECT public.c77_rbac_revoke_subject_role('user3', 'test_role', 'department', 'engineering');

Step 5: Update Application Code

After successful upgrade, you can now use new features in your application:

// Laravel example - using new bulk operations
$userIds = ['1001', '1002', '1003', '1004', '1005'];
$results = DB::select("
    SELECT * FROM public.c77_rbac_bulk_assign_subjects(?, ?, ?, ?)
", [json_encode($userIds), 'student', 'program', 'dui_education']);

foreach ($results as $result) {
    if (!$result->success) {
        Log::warning("Failed to assign role to user {$result->external_id}: {$result->error_message}");
    }
}

Post-Installation Verification

Comprehensive Testing Script

Create a test script to verify all functionality:

-- test_c77_rbac_installation.sql

\echo 'Testing c77_rbac installation...'

-- Test 1: Basic feature granting
\echo 'Test 1: Feature granting'
SELECT public.c77_rbac_grant_feature('admin', 'manage_users');
SELECT public.c77_rbac_grant_feature('manager', 'view_reports');
SELECT public.c77_rbac_grant_feature('employee', 'view_own_data');

-- Test 2: Role assignment
\echo 'Test 2: Role assignment'
SELECT public.c77_rbac_assign_subject('admin_user', 'admin', 'global', 'all');
SELECT public.c77_rbac_assign_subject('dept_manager', 'manager', 'department', 'sales');
SELECT public.c77_rbac_assign_subject('employee_1', 'employee', 'department', 'sales');

-- Test 3: Bulk assignment (v1.1 feature)
\echo 'Test 3: Bulk assignment'
SELECT * FROM public.c77_rbac_bulk_assign_subjects(
    ARRAY['emp_1', 'emp_2', 'emp_3'],
    'employee',
    'department',
    'engineering'
);

-- Test 4: Permission checking
\echo 'Test 4: Permission checking'
SELECT public.c77_rbac_can_access('manage_users', 'admin_user', 'global', 'all') as admin_can_manage;
SELECT public.c77_rbac_can_access('view_reports', 'dept_manager', 'department', 'sales') as manager_can_view;
SELECT public.c77_rbac_can_access('manage_users', 'employee_1', 'department', 'sales') as employee_cannot_manage;

-- Test 5: Management views (v1.1 feature)
\echo 'Test 5: Management views'
SELECT * FROM public.c77_rbac_summary;
SELECT * FROM public.c77_rbac_get_user_roles('admin_user');

-- Test 6: Admin sync (v1.1 feature)
\echo 'Test 6: Admin sync'
SELECT public.c77_rbac_sync_admin_features();

-- Test 7: Removal functions (v1.1 feature)
\echo 'Test 7: Removal functions'
SELECT public.c77_rbac_revoke_subject_role('emp_1', 'employee', 'department', 'engineering');
SELECT public.c77_rbac_revoke_feature('employee', 'temporary_feature');

-- Cleanup
\echo 'Cleaning up test data...'
DELETE FROM public.c77_rbac_subject_roles;
DELETE FROM public.c77_rbac_role_features;
DELETE FROM public.c77_rbac_subjects;
DELETE FROM public.c77_rbac_roles;
DELETE FROM public.c77_rbac_features;

\echo 'Installation test complete!'

Run the test:

sudo -u postgres psql -d myapp_production -f test_c77_rbac_installation.sql

Performance Testing

Test with larger datasets:

-- Performance test script
DO $$
DECLARE
    start_time TIMESTAMP;
    end_time TIMESTAMP;
    i INTEGER;
BEGIN
    start_time := clock_timestamp();
    
    -- Create test features
    FOR i IN 1..100 LOOP
        PERFORM public.c77_rbac_grant_feature('perf_role', 'feature_' || i);
    END LOOP;
    
    end_time := clock_timestamp();
    RAISE NOTICE 'Feature creation time: %', end_time - start_time;
    
    start_time := clock_timestamp();
    
    -- Test bulk assignment
    PERFORM public.c77_rbac_bulk_assign_subjects(
        array_agg('user_' || generate_series),
        'perf_role',
        'department',
        'performance_test'
    ) FROM generate_series(1, 1000);
    
    end_time := clock_timestamp();
    RAISE NOTICE 'Bulk assignment time (1000 users): %', end_time - start_time;
    
    start_time := clock_timestamp();
    
    -- Test permission checking
    FOR i IN 1..100 LOOP
        PERFORM public.c77_rbac_can_access('feature_1', 'user_' || i, 'department', 'performance_test');
    END LOOP;
    
    end_time := clock_timestamp();
    RAISE NOTICE 'Permission check time (100 checks): %', end_time - start_time;
END $$;

Initial Configuration

Example: Court Education System Setup

After installation, configure for your specific use case:

-- court_system_setup.sql

-- Step 1: Create court-specific roles and features
SELECT public.c77_rbac_grant_feature('court_admin', 'manage_all_programs');
SELECT public.c77_rbac_grant_feature('court_admin', 'view_all_participants');
SELECT public.c77_rbac_grant_feature('court_admin', 'generate_court_reports');
SELECT public.c77_rbac_grant_feature('court_admin', 'manage_users');

SELECT public.c77_rbac_grant_feature('judge', 'view_court_participants');
SELECT public.c77_rbac_grant_feature('judge', 'approve_completions');
SELECT public.c77_rbac_grant_feature('judge', 'access_court_reports');

SELECT public.c77_rbac_grant_feature('court_clerk', 'enroll_participants');
SELECT public.c77_rbac_grant_feature('court_clerk', 'view_court_participants');
SELECT public.c77_rbac_grant_feature('court_clerk', 'update_participant_info');

SELECT public.c77_rbac_grant_feature('program_coordinator', 'manage_programs');
SELECT public.c77_rbac_grant_feature('program_coordinator', 'view_program_participants');
SELECT public.c77_rbac_grant_feature('program_coordinator', 'update_progress');

SELECT public.c77_rbac_grant_feature('counselor', 'view_assigned_participants');
SELECT public.c77_rbac_grant_feature('counselor', 'update_progress');
SELECT public.c77_rbac_grant_feature('counselor', 'mark_attendance');

SELECT public.c77_rbac_grant_feature('participant', 'view_own_progress');
SELECT public.c77_rbac_grant_feature('participant', 'access_program_materials');

-- Step 2: Sync admin features
SELECT public.c77_rbac_sync_admin_features();

-- Step 3: Assign initial users
-- System administrator
SELECT public.c77_rbac_assign_subject('1', 'court_admin', 'global', 'all');

-- County Superior Court judge
SELECT public.c77_rbac_assign_subject('101', 'judge', 'court', 'county_superior');

-- Court clerk for county superior
SELECT public.c77_rbac_assign_subject('201', 'court_clerk', 'court', 'county_superior');

-- DUI program coordinator
SELECT public.c77_rbac_assign_subject('301', 'program_coordinator', 'program', 'dui_education');

-- Step 4: Apply security policies to tables (after creating your tables)
-- SELECT public.c77_rbac_apply_policy('participants', 'view_court_participants', 'court', 'assigned_court');
-- SELECT public.c77_rbac_apply_policy('participant_progress', 'view_own_progress', 'participant', 'participant_id');
-- SELECT public.c77_rbac_apply_policy('programs', 'manage_programs', 'program', 'program_type');

-- Step 5: Verify setup
SELECT * FROM public.c77_rbac_summary;

Laravel Environment Configuration

Update your .env file:

DB_CONNECTION=pgsql
DB_HOST=127.0.0.1
DB_PORT=5432
DB_DATABASE=myapp_production
DB_USERNAME=myapp_user
DB_PASSWORD=your_very_secure_password_here

# Optional: Enable query logging for debugging
DB_LOG_QUERIES=true

Troubleshooting Installation Issues

Common Installation Problems

Problem 1: Permission Denied Copying Files

Error:

cp: cannot create regular file '/usr/share/postgresql/14/extension/c77_rbac.control': Permission denied

Solution:

# Use sudo for copying files
sudo cp c77_rbac.control /usr/share/postgresql/14/extension/

# Or change to postgres user temporarily
sudo su - postgres
cp /path/to/c77_rbac.control /usr/share/postgresql/14/extension/
exit

Problem 2: Extension Directory Not Found

Error:

cp: cannot stat '/usr/share/postgresql/14/extension/': No such file or directory

Solution:

# Find the correct PostgreSQL installation
pg_config --sharedir

# Or search for extension directories
find /usr -name "extension" -type d 2>/dev/null | grep postgresql

# Common locations:
# Ubuntu/Debian: /usr/share/postgresql/14/extension/
# CentOS/RHEL: /usr/pgsql-14/share/extension/
# macOS Homebrew: /opt/homebrew/share/postgresql@14/extension/

Problem 3: Extension Creation Fails

Error:

ERROR: could not open extension control file "/usr/share/postgresql/14/extension/c77_rbac.control": No such file or directory

Solution:

# Verify files are in correct location
ls -la /usr/share/postgresql/14/extension/c77_rbac*

# Check file permissions
sudo chmod 644 /usr/share/postgresql/14/extension/c77_rbac*

# Restart PostgreSQL if necessary
sudo systemctl restart postgresql

Problem 4: Upgrade Fails

Error:

ERROR: extension "c77_rbac" has no update path from version "1.0" to version "1.1"

Solution:

# Verify upgrade script exists
ls -la /usr/share/postgresql/14/extension/c77_rbac--1.0--1.1.sql

# Check control file has correct version
cat /usr/share/postgresql/14/extension/c77_rbac.control

# Reload configuration
sudo systemctl reload postgresql

Diagnostic Commands

-- Check extension status
SELECT * FROM pg_extension WHERE extname = 'c77_rbac';

-- Check available versions
SELECT name, version, comment FROM pg_available_extensions WHERE name = 'c77_rbac';

-- Check update paths
SELECT * FROM pg_extension_update_paths('c77_rbac');

-- Verify tables exist
SELECT tablename FROM pg_tables WHERE tablename LIKE 'c77_rbac_%';

-- Check function permissions
SELECT routine_name, specific_name FROM information_schema.routines 
WHERE routine_name LIKE 'c77_rbac_%';

Log Analysis

Check PostgreSQL logs for detailed error information:

# Ubuntu/Debian
sudo tail -f /var/log/postgresql/postgresql-14-main.log

# CentOS/RHEL
sudo tail -f /var/lib/pgsql/14/data/log/postgresql-*.log

# macOS Homebrew
tail -f /opt/homebrew/var/log/postgresql@14.log

Uninstallation

Safe Uninstallation Process

  1. Check dependencies first:

    SELECT * FROM public.c77_rbac_show_dependencies();
    
  2. Remove all RLS policies:

    SELECT public.c77_rbac_remove_all_policies();
    
  3. Optionally backup RBAC data:

    COPY (SELECT * FROM public.c77_rbac_user_permissions) TO '/tmp/rbac_backup.csv' CSV HEADER;
    
  4. Complete cleanup:

    SELECT public.c77_rbac_cleanup_for_removal(true);  -- true = remove data
    
  5. Drop the extension:

    DROP EXTENSION c77_rbac CASCADE;
    
  6. Remove files from system:

    sudo rm /usr/share/postgresql/14/extension/c77_rbac*
    

Production Deployment Checklist

Pre-Deployment

  • Database backup completed
  • Extension files copied to production server
  • PostgreSQL service restarted/reloaded
  • Test environment upgrade successful
  • Application code updated to handle new features
  • Rollback plan prepared

Deployment Steps

  • Connect as superuser
  • Install/upgrade extension
  • Verify installation with test script
  • Grant privileges to application users
  • Configure initial roles and features
  • Apply RLS policies to application tables
  • Test application connectivity

Post-Deployment

  • Monitor PostgreSQL logs for errors
  • Verify application functionality
  • Check performance metrics
  • Update monitoring alerts
  • Document installation for team

Production Configuration Example

#!/bin/bash
# production_deploy.sh

set -e  # Exit on any error

echo "Starting c77_rbac production deployment..."

# Backup database
pg_dump -U postgres -h localhost myapp_production > backup_$(date +%Y%m%d_%H%M%S).sql

# Copy extension files
sudo cp c77_rbac.control /usr/share/postgresql/14/extension/
sudo cp c77_rbac--1.1.sql /usr/share/postgresql/14/extension/

# Install extension
sudo -u postgres psql -d myapp_production -c "CREATE EXTENSION IF NOT EXISTS c77_rbac;"

# Verify installation
sudo -u postgres psql -d myapp_production -c "SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_rbac';"

# Run initialization script
sudo -u postgres psql -d myapp_production -f court_system_setup.sql

echo "Deployment completed successfully!"

This installation guide provides comprehensive coverage of all installation scenarios with detailed examples and troubleshooting information. The step-by-step approach ensures successful deployment in any environment.