diff --git a/backend/database/migrations/000001_initial_schema.down.sql b/backend/database/migrations/000001_initial_schema.down.sql new file mode 100644 index 0000000..13552c2 --- /dev/null +++ b/backend/database/migrations/000001_initial_schema.down.sql @@ -0,0 +1,33 @@ +-- ============================================================================= +-- ROLLBACK: 000001_initial_schema +-- ============================================================================= + +-- Drop tables in reverse order (respecting foreign keys) +DROP TABLE IF EXISTS notifications CASCADE; +DROP TABLE IF EXISTS analytics_events CASCADE; +DROP TABLE IF EXISTS audit_logs CASCADE; +DROP TABLE IF EXISTS attachments CASCADE; +DROP TABLE IF EXISTS comments CASCADE; +DROP TABLE IF EXISTS milestones CASCADE; +DROP TABLE IF EXISTS deliverables CASCADE; +DROP TABLE IF EXISTS contracts CASCADE; +DROP TABLE IF EXISTS users CASCADE; +DROP TABLE IF EXISTS tenants CASCADE; + +-- Drop functions +DROP FUNCTION IF EXISTS update_updated_at_column() CASCADE; +DROP FUNCTION IF EXISTS set_tenant_context(UUID) CASCADE; +DROP FUNCTION IF EXISTS get_current_tenant() CASCADE; + +-- Drop enums +DROP TYPE IF EXISTS milestone_status CASCADE; +DROP TYPE IF EXISTS milestone_type CASCADE; +DROP TYPE IF EXISTS deliverable_status CASCADE; +DROP TYPE IF EXISTS contract_status CASCADE; +DROP TYPE IF EXISTS tenant_type CASCADE; +DROP TYPE IF EXISTS user_role CASCADE; + +-- Drop extensions (optional - might be used by other databases) +-- DROP EXTENSION IF EXISTS "btree_gin"; +-- DROP EXTENSION IF EXISTS "pg_trgm"; +-- DROP EXTENSION IF EXISTS "uuid-ossp"; \ No newline at end of file diff --git a/backend/database/migrations/000001_initial_schema.up.sql b/backend/database/migrations/000001_initial_schema.up.sql new file mode 100644 index 0000000..80c4671 --- /dev/null +++ b/backend/database/migrations/000001_initial_schema.up.sql @@ -0,0 +1,537 @@ +-- ============================================================================= +-- AURGANIZE V6.2 - INITIAL SCHEMA (CORRECTED) +-- ============================================================================= +-- Migration: 000001_initial_schema +-- Description: Creates core tables for multi-tenant project management +-- Author: Aurganize Team +-- Date: 2025-11-26 +-- ============================================================================= + +-- ============================================================================= +-- EXTENSIONS +-- ============================================================================= + +CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; +CREATE EXTENSION IF NOT EXISTS "pg_trgm"; +CREATE EXTENSION IF NOT EXISTS "btree_gin"; + +-- ============================================================================= +-- ENUMS +-- ============================================================================= + +CREATE TYPE user_role AS ENUM ('admin', 'vendor', 'consumer', 'project_manager'); +CREATE TYPE tenant_type AS ENUM ('permanent', 'temporary'); +CREATE TYPE contract_status AS ENUM ('draft', 'active', 'completed', 'cancelled'); +CREATE TYPE deliverable_status AS ENUM ('pending', 'in_progress', 'submitted', 'approved', 'rejected'); +CREATE TYPE milestone_type AS ENUM ('fixed_date', 'duration_from_start', 'duration_from_previous'); +CREATE TYPE milestone_status AS ENUM ('pending', 'in_progress', 'completed'); + +-- ============================================================================= +-- CORE TABLES +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- Tenants Table +-- ----------------------------------------------------------------------------- +-- Stores tenant (organization) information +-- Supports both permanent tenants (companies) and temporary tenants (projects) + +CREATE TABLE tenants ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + name VARCHAR(255) NOT NULL, + type tenant_type NOT NULL DEFAULT 'permanent', + parent_tenant_id UUID REFERENCES tenants(id) ON DELETE CASCADE, + is_active BOOLEAN NOT NULL DEFAULT true, + expires_at TIMESTAMPTZ, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT valid_tenant_type CHECK ( + (type = 'permanent' AND parent_tenant_id IS NULL AND expires_at IS NULL) OR + (type = 'temporary' AND parent_tenant_id IS NOT NULL AND expires_at IS NOT NULL) + ) +); + +-- Indexes +CREATE INDEX idx_tenants_parent ON tenants(parent_tenant_id) WHERE parent_tenant_id IS NOT NULL; +CREATE INDEX idx_tenants_active ON tenants(is_active) WHERE is_active = true; +CREATE INDEX idx_tenants_expires ON tenants(expires_at) WHERE expires_at IS NOT NULL; + +-- Comments +COMMENT ON TABLE tenants IS 'Organizations and project workspaces'; +COMMENT ON COLUMN tenants.type IS 'permanent: Long-lived organization, temporary: Project-specific workspace'; +COMMENT ON COLUMN tenants.parent_tenant_id IS 'For temporary tenants, links to parent permanent tenant'; + +-- ----------------------------------------------------------------------------- +-- Users Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE users ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Authentication + email VARCHAR(255) NOT NULL, + password_hash TEXT NOT NULL, + + -- Profile + name VARCHAR(255) NOT NULL, + avatar_url TEXT, + role user_role NOT NULL DEFAULT 'consumer', + + -- Status + is_active BOOLEAN NOT NULL DEFAULT true, + email_verified_at TIMESTAMPTZ, + last_login_at TIMESTAMPTZ, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT unique_email_per_tenant UNIQUE(tenant_id, email), + CONSTRAINT valid_email CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$') +); + +-- Indexes +CREATE INDEX idx_users_tenant ON users(tenant_id); +CREATE INDEX idx_users_email ON users(email); +CREATE INDEX idx_users_role ON users(role); +CREATE INDEX idx_users_active ON users(is_active) WHERE is_active = true; + +-- Comments +COMMENT ON TABLE users IS 'User accounts with multi-tenant support'; +COMMENT ON CONSTRAINT unique_email_per_tenant ON users IS 'Email must be unique within a tenant, but can exist in multiple tenants'; + +-- ----------------------------------------------------------------------------- +-- Contracts Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE contracts ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Parties + vendor_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, + consumer_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, + + -- Details + title VARCHAR(500) NOT NULL, + description TEXT, + status contract_status NOT NULL DEFAULT 'draft', + + -- Dates + start_date DATE NOT NULL, + end_date DATE NOT NULL, + + -- Financial + total_amount NUMERIC(12,2) NOT NULL DEFAULT 0.00, + currency VARCHAR(3) NOT NULL DEFAULT 'USD', + + -- Version control (optimistic locking) + version INTEGER NOT NULL DEFAULT 1, + + -- Metadata + created_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT valid_dates CHECK (end_date > start_date), + CONSTRAINT valid_amount CHECK (total_amount >= 0), + CONSTRAINT different_parties CHECK (vendor_id != consumer_id) +); + +-- Indexes +CREATE INDEX idx_contracts_tenant ON contracts(tenant_id); +CREATE INDEX idx_contracts_vendor ON contracts(vendor_id); +CREATE INDEX idx_contracts_consumer ON contracts(consumer_id); +CREATE INDEX idx_contracts_status ON contracts(status); +CREATE INDEX idx_contracts_dates ON contracts(start_date, end_date); +CREATE INDEX idx_contracts_search ON contracts USING GIN(to_tsvector('english', title || ' ' || COALESCE(description, ''))); + +-- Comments +COMMENT ON TABLE contracts IS 'Agreements between vendors and consumers'; +COMMENT ON COLUMN contracts.version IS 'For optimistic locking - increment on each update'; + +-- ----------------------------------------------------------------------------- +-- Deliverables Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE deliverables ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + contract_id UUID NOT NULL REFERENCES contracts(id) ON DELETE CASCADE, + + -- Details + title VARCHAR(500) NOT NULL, + description TEXT, + sequence_number INTEGER NOT NULL, + status deliverable_status NOT NULL DEFAULT 'pending', + + -- Dates + deadline DATE NOT NULL, + submitted_at TIMESTAMPTZ, + approved_at TIMESTAMPTZ, + + -- Submission + submitted_by UUID REFERENCES users(id) ON DELETE SET NULL, + approved_by UUID REFERENCES users(id) ON DELETE SET NULL, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT unique_sequence_per_contract UNIQUE(contract_id, sequence_number), + CONSTRAINT valid_sequence CHECK (sequence_number > 0) +); + +-- Indexes +CREATE INDEX idx_deliverables_tenant ON deliverables(tenant_id); +CREATE INDEX idx_deliverables_contract ON deliverables(contract_id); +CREATE INDEX idx_deliverables_status ON deliverables(status); +CREATE INDEX idx_deliverables_deadline ON deliverables(deadline); + +-- Comments +COMMENT ON TABLE deliverables IS 'Work items to be delivered as part of contracts'; +COMMENT ON COLUMN deliverables.sequence_number IS 'Order of deliverable in contract (1, 2, 3...)'; + +-- ----------------------------------------------------------------------------- +-- Milestones Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE milestones ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + deliverable_id UUID NOT NULL REFERENCES deliverables(id) ON DELETE CASCADE, + + -- Details + title VARCHAR(500) NOT NULL, + type milestone_type NOT NULL, + condition_value VARCHAR(100) NOT NULL, + amount NUMERIC(12,2) NOT NULL DEFAULT 0.00, + status milestone_status NOT NULL DEFAULT 'pending', + + -- Tracking + completed_at TIMESTAMPTZ, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT valid_amount CHECK (amount >= 0) +); + +-- Indexes +CREATE INDEX idx_milestones_tenant ON milestones(tenant_id); +CREATE INDEX idx_milestones_deliverable ON milestones(deliverable_id); +CREATE INDEX idx_milestones_status ON milestones(status); + +-- Comments +COMMENT ON TABLE milestones IS 'Payment milestones within deliverables'; +COMMENT ON COLUMN milestones.type IS 'Determines how condition_value is interpreted'; +COMMENT ON COLUMN milestones.condition_value IS 'Date or duration depending on type'; + +-- ----------------------------------------------------------------------------- +-- Comments Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE comments ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Polymorphic relation + entity_type VARCHAR(50) NOT NULL, + entity_id UUID NOT NULL, + + -- Content + content TEXT NOT NULL, + + -- Author + user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT valid_entity_type CHECK (entity_type IN ('contract', 'deliverable', 'milestone')) +); + +-- Indexes +CREATE INDEX idx_comments_tenant ON comments(tenant_id); +CREATE INDEX idx_comments_entity ON comments(entity_type, entity_id); +CREATE INDEX idx_comments_user ON comments(user_id); +CREATE INDEX idx_comments_created ON comments(created_at DESC); + +-- Comments +COMMENT ON TABLE comments IS 'Discussion comments on various entities'; +COMMENT ON COLUMN comments.entity_type IS 'Type of entity: contract, deliverable, milestone'; +COMMENT ON COLUMN comments.entity_id IS 'ID of the entity (contract, deliverable, or milestone)'; + +-- ----------------------------------------------------------------------------- +-- Attachments Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE attachments ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Polymorphic relation + entity_type VARCHAR(50) NOT NULL, + entity_id UUID NOT NULL, + + -- File details + filename VARCHAR(255) NOT NULL, + content_type VARCHAR(100) NOT NULL, + size BIGINT NOT NULL, + object_name TEXT NOT NULL, + + -- Status + status VARCHAR(20) NOT NULL DEFAULT 'pending', + + -- Tracking + uploaded_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, + uploaded_at TIMESTAMPTZ, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), + deleted_at TIMESTAMPTZ, + + -- Constraints + CONSTRAINT valid_size CHECK (size > 0), + CONSTRAINT valid_status CHECK (status IN ('pending', 'uploaded', 'processing', 'failed')), + CONSTRAINT valid_entity_type CHECK (entity_type IN ('contract', 'deliverable', 'milestone', 'comment')) +); + +-- Indexes +CREATE INDEX idx_attachments_tenant ON attachments(tenant_id); +CREATE INDEX idx_attachments_entity ON attachments(entity_type, entity_id); +CREATE INDEX idx_attachments_uploaded_by ON attachments(uploaded_by); +CREATE INDEX idx_attachments_status ON attachments(status); + +-- Comments +COMMENT ON TABLE attachments IS 'File attachments for various entities'; +COMMENT ON COLUMN attachments.object_name IS 'Object key in MinIO/S3'; + +-- ============================================================================= +-- AUDIT TABLES +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- Audit Logs Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE audit_logs ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Action details + action VARCHAR(100) NOT NULL, + entity_type VARCHAR(50) NOT NULL, + entity_id UUID NOT NULL, + + -- Actor + actor_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, + + -- Changes + old_values JSONB, + new_values JSONB, + + -- Context + ip_address INET, + user_agent TEXT, + + -- Timestamp + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() +); + +-- Indexes +CREATE INDEX idx_audit_tenant ON audit_logs(tenant_id); +CREATE INDEX idx_audit_entity ON audit_logs(entity_type, entity_id); +CREATE INDEX idx_audit_actor ON audit_logs(actor_id); +CREATE INDEX idx_audit_action ON audit_logs(action); +CREATE INDEX idx_audit_created ON audit_logs(created_at DESC); +CREATE INDEX idx_audit_values ON audit_logs USING GIN(old_values, new_values); + +-- Comments +COMMENT ON TABLE audit_logs IS 'Audit trail of all important actions'; +COMMENT ON COLUMN audit_logs.action IS 'e.g., contract.created, deliverable.submitted'; + +-- ----------------------------------------------------------------------------- +-- Analytics Events Table +-- ----------------------------------------------------------------------------- + +CREATE TABLE analytics_events ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID REFERENCES tenants(id) ON DELETE CASCADE, + + -- Event details + event_type VARCHAR(100) NOT NULL, + event_data JSONB NOT NULL DEFAULT '{}', + + -- User (nullable for anonymous events) + user_id UUID REFERENCES users(id) ON DELETE SET NULL, + + -- Context + ip_address INET, + user_agent TEXT, + + -- Timestamp + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() +); + +-- Indexes +CREATE INDEX idx_analytics_tenant ON analytics_events(tenant_id); +CREATE INDEX idx_analytics_type ON analytics_events(event_type); +CREATE INDEX idx_analytics_user ON analytics_events(user_id); +CREATE INDEX idx_analytics_created ON analytics_events(created_at DESC); +CREATE INDEX idx_analytics_data ON analytics_events USING GIN(event_data); + +-- Comments +COMMENT ON TABLE analytics_events IS 'User behavior and system events for analytics'; + +-- ============================================================================= +-- NOTIFICATION TABLES +-- ============================================================================= + +CREATE TABLE notifications ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, + + -- Recipient + user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, + + -- Content + type VARCHAR(50) NOT NULL, + title VARCHAR(255) NOT NULL, + message TEXT NOT NULL, + + -- Related entity + entity_type VARCHAR(50), + entity_id UUID, + + -- Status + read_at TIMESTAMPTZ, + + -- Metadata + created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() +); + +-- Indexes +CREATE INDEX idx_notifications_tenant ON notifications(tenant_id); +CREATE INDEX idx_notifications_user ON notifications(user_id); +CREATE INDEX idx_notifications_unread ON notifications(user_id, read_at) WHERE read_at IS NULL; +CREATE INDEX idx_notifications_entity ON notifications(entity_type, entity_id); +CREATE INDEX idx_notifications_created ON notifications(created_at DESC); + +-- Comments +COMMENT ON TABLE notifications IS 'In-app notifications for users'; + +-- ============================================================================= +-- TRIGGERS FOR UPDATED_AT +-- ============================================================================= + +-- Function to update updated_at timestamp +CREATE OR REPLACE FUNCTION update_updated_at_column() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at = NOW(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +-- Apply to all tables with updated_at +CREATE TRIGGER update_tenants_updated_at BEFORE UPDATE ON tenants + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_contracts_updated_at BEFORE UPDATE ON contracts + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_deliverables_updated_at BEFORE UPDATE ON deliverables + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_milestones_updated_at BEFORE UPDATE ON milestones + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_comments_updated_at BEFORE UPDATE ON comments + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +CREATE TRIGGER update_attachments_updated_at BEFORE UPDATE ON attachments + FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); + +-- ============================================================================= +-- ROW-LEVEL SECURITY +-- ============================================================================= + +-- Enable RLS on all tenant-scoped tables +ALTER TABLE tenants ENABLE ROW LEVEL SECURITY; +ALTER TABLE users ENABLE ROW LEVEL SECURITY; +ALTER TABLE contracts ENABLE ROW LEVEL SECURITY; +ALTER TABLE deliverables ENABLE ROW LEVEL SECURITY; +ALTER TABLE milestones ENABLE ROW LEVEL SECURITY; +ALTER TABLE comments ENABLE ROW LEVEL SECURITY; +ALTER TABLE attachments ENABLE ROW LEVEL SECURITY; +ALTER TABLE audit_logs ENABLE ROW LEVEL SECURITY; +ALTER TABLE analytics_events ENABLE ROW LEVEL SECURITY; +ALTER TABLE notifications ENABLE ROW LEVEL SECURITY; + +-- Create policies +CREATE POLICY tenants_tenant_isolation ON tenants + USING (id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY users_tenant_isolation ON users + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY contracts_tenant_isolation ON contracts + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY deliverables_tenant_isolation ON deliverables + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY milestones_tenant_isolation ON milestones + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY comments_tenant_isolation ON comments + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY attachments_tenant_isolation ON attachments + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY audit_logs_tenant_isolation ON audit_logs + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +CREATE POLICY analytics_events_tenant_isolation ON analytics_events + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID OR tenant_id IS NULL) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID OR tenant_id IS NULL); + +CREATE POLICY notifications_tenant_isolation ON notifications + USING (tenant_id = current_setting('app.current_tenant_id', true)::UUID) + WITH CHECK (tenant_id = current_setting('app.current_tenant_id', true)::UUID); + +-- ============================================================================= +-- END OF MIGRATION +-- ============================================================================= \ No newline at end of file diff --git a/backend/database/scripts/backup_db.sh b/backend/database/scripts/backup_db.sh new file mode 100644 index 0000000..62b53f5 --- /dev/null +++ b/backend/database/scripts/backup_db.sh @@ -0,0 +1,75 @@ +#!/bin/bash +# database/scripts/backup.sh +set -e + +# ============================================================================ +# CONFIGURATION +# ============================================================================ + +CONTAINER_NAME="${CONTAINER_NAME:-aurganize-postgres}" + +# Host directory (on your laptop / machine) +BACKUP_DIR="${BACKUP_DIR:-$HOME/workspace/db_backup/aurganize_backups}" + +DB_NAME="${DB_NAME:-aurganize_dev}" +DB_USER="${DB_USER:-aurganize_backend_api}" +RETENTION_DAYS="${RETENTION_DAYS:-30}" + +# Ensure host backup directory exists +mkdir -p "${BACKUP_DIR}" + +# Timestamped filename on host +TIMESTAMP=$(date +"%Y%m%d_%H%M%S") +BACKUP_FILE="${BACKUP_DIR}/${DB_NAME}_${TIMESTAMP}.sql.gz" + +echo "===================================================================" +echo "PostgreSQL Backup (Docker) - $(date)" +echo "===================================================================" +echo "Container: ${CONTAINER_NAME}" +echo "Database : ${DB_NAME}" +echo "Backup : ${BACKUP_FILE}" +echo "" + +# ============================================================================ +# BACKUP EXECUTION +# ============================================================================ + +echo "Creating backup inside Docker container..." + +docker exec -i "${CONTAINER_NAME}" \ + pg_dump -U "${DB_USER}" -d "${DB_NAME}" --format=plain --no-owner --no-privileges \ + | gzip > "${BACKUP_FILE}" + +# ============================================================================ +# VERIFY BACKUP +# ============================================================================ + +if [ -f "${BACKUP_FILE}" ]; then + SIZE=$(du -h "${BACKUP_FILE}" | cut -f1) + echo "✓ Backup created successfully (${SIZE})" +else + echo "✗ Backup failed!" + exit 1 +fi + +# ============================================================================ +# CLEANUP OLD BACKUPS +# ============================================================================ + +echo "" +echo "Cleaning up old backups (older than ${RETENTION_DAYS} days)..." + +find "${BACKUP_DIR}" -name "${DB_NAME}_*.sql.gz" -type f -mtime +${RETENTION_DAYS} -delete + +# ============================================================================ +# LIST BACKUPS +# ============================================================================ + +echo "" +echo "Available backups:" +ls -lh "${BACKUP_DIR}/${DB_NAME}"_*.sql.gz 2>/dev/null || echo "No backups found." + +echo "" +echo "===================================================================" +echo "Backup Complete!" +echo "===================================================================" diff --git a/backend/database/scripts/configure-postgres.sh b/backend/database/scripts/configure-postgres.sh new file mode 100644 index 0000000..fb03ccd --- /dev/null +++ b/backend/database/scripts/configure-postgres.sh @@ -0,0 +1,85 @@ +#!/bin/bash +# database/scripts/configure-postgres.sh +# +# PostgreSQL Configuration Management Script +# Applies recommended settings based on system resources +# NOTE THIS FILE IS FOR REFERENCE PURPOSE ONLY SINCE WE ARE USING INSIDE A DOCKER CONTAINER +# - WE HAVE FIND ANOTHER WAY TO PROVISION THIS SHELL SCRIPT +# -- DO NOT USE +set -e + +# Colors for output +RED='\033[0;31m' +GREEN='\033[0;32m' +YELLOW='\033[1;33m' +NC='\033[0m' # No Color + +echo "===================================================================" +echo "PostgreSQL Configuration Script for Aurganize V6.2" +echo "===================================================================" + +# Check if running as root +if [[ $EUID -ne 0 ]]; then + echo -e "${RED}This script must be run as root${NC}" + exit 1 +fi + +# Detect PostgreSQL version +PG_VERSION=$(sudo -u postgres psql -t -c "SELECT version();" | grep -oP '\d+(?:\.\d+)?' | head -1 | cut -d. -f1) +echo -e "${GREEN}Detected PostgreSQL version: ${PG_VERSION}${NC}" + +# Detect total RAM +TOTAL_RAM_KB=$(grep MemTotal /proc/meminfo | awk '{print $2}') +TOTAL_RAM_GB=$((TOTAL_RAM_KB / 1024 / 1024)) +echo -e "${GREEN}Detected RAM: ${TOTAL_RAM_GB}GB${NC}" + +# Calculate settings +SHARED_BUFFERS_GB=$((TOTAL_RAM_GB / 4)) +EFFECTIVE_CACHE_GB=$((TOTAL_RAM_GB * 3 / 4)) +WORK_MEM_MB=$(((TOTAL_RAM_GB - SHARED_BUFFERS_GB) * 1024 / 100 / 3)) + +echo "" +echo "Recommended settings:" +echo " shared_buffers = ${SHARED_BUFFERS_GB}GB" +echo " effective_cache_size = ${EFFECTIVE_CACHE_GB}GB" +echo " work_mem = ${WORK_MEM_MB}MB" +echo "" + +# Ask for confirmation +read -p "Apply these settings? (y/n) " -n 1 -r +echo +if [[ ! $REPLY =~ ^[Yy]$ ]]; then + echo "Aborted." + exit 0 +fi + +# Backup current config +CONFIG_FILE="/etc/postgresql/${PG_VERSION}/main/postgresql.conf" +BACKUP_FILE="${CONFIG_FILE}.backup.$(date +%Y%m%d_%H%M%S)" + +echo -e "${YELLOW}Backing up config to: ${BACKUP_FILE}${NC}" +cp "${CONFIG_FILE}" "${BACKUP_FILE}" + +# Apply settings +echo -e "${GREEN}Applying settings...${NC}" + +sudo -u postgres psql -c "ALTER SYSTEM SET shared_buffers = '${SHARED_BUFFERS_GB}GB';" +sudo -u postgres psql -c "ALTER SYSTEM SET effective_cache_size = '${EFFECTIVE_CACHE_GB}GB';" +sudo -u postgres psql -c "ALTER SYSTEM SET work_mem = '${WORK_MEM_MB}MB';" +sudo -u postgres psql -c "ALTER SYSTEM SET maintenance_work_mem = '256MB';" +sudo -u postgres psql -c "ALTER SYSTEM SET random_page_cost = '1.1';" +sudo -u postgres psql -c "ALTER SYSTEM SET effective_io_concurrency = '200';" + +# Restart PostgreSQL +echo -e "${YELLOW}Restarting PostgreSQL...${NC}" +systemctl restart postgresql + +# Verify +echo -e "${GREEN}Configuration applied successfully!${NC}" +sudo -u postgres psql -c "SELECT name, setting, unit FROM pg_settings WHERE name IN ('shared_buffers', 'effective_cache_size', 'work_mem');" + +echo "" +echo "===================================================================" +echo "Configuration complete!" +echo "Backup saved to: ${BACKUP_FILE}" +echo "===================================================================" \ No newline at end of file diff --git a/backend/database/scripts/dev_seed.sh b/backend/database/scripts/dev_seed.sh new file mode 100644 index 0000000..c5b34f7 --- /dev/null +++ b/backend/database/scripts/dev_seed.sh @@ -0,0 +1,14 @@ +#!/bin/bash +set -e + +CONTAINER="aurganize-postgres" +DB_USER="postgres" +DB_NAME="aurganize_dev" +SEED_FILE="$(dirname "$0")/../seeds/001_dev_data.sql" + +echo "Running development seeds..." + +docker exec -i "$CONTAINER" \ + psql -U "$DB_USER" -d "$DB_NAME" < "$SEED_FILE" + +echo "✓ Development seed data loaded successfully" diff --git a/backend/database/scripts/health_check.sh b/backend/database/scripts/health_check.sh new file mode 100644 index 0000000..05855c2 --- /dev/null +++ b/backend/database/scripts/health_check.sh @@ -0,0 +1,33 @@ +#!/bin/bash +# database/scripts/health_check.sh + +set -e + +CONTAINER_NAME="${CONTAINER_NAME:-aurganize-postgres}" +DB_USER="${DB_USER:-postgres}" + +# Updated path to match your new location +SQL_FILE="$(dirname "$0")/../tests/health_check.sql" + +echo "===================================================================" +echo "Running PostgreSQL Health Check (Docker)" +echo "Container : ${CONTAINER_NAME}" +echo "SQL File : ${SQL_FILE}" +echo "===================================================================" +echo "" + +# Ensure SQL file exists +if [ ! -f "$SQL_FILE" ]; then + echo "❌ SQL file not found: $SQL_FILE" + exit 1 +fi + +docker exec -i "${CONTAINER_NAME}" \ + psql -U "${DB_USER}" -f - <" + exit 1 + fi + echo "⚠️ Forcing version to $2..." + migrate -path "${MIGRATIONS_DIR}" -database "${DATABASE_URL}" force "$2" + echo -e "${GREEN}✓ Version forced${NC}" + ;; + + *) + echo "Usage: $0 {up|down|version|force }" + echo "" + echo "Commands:" + echo " up Apply all pending migrations" + echo " down Rollback the last migration" + echo " version Show current migration version" + echo " force Force database to specific version (use with caution!)" + exit 1 + ;; +esac \ No newline at end of file diff --git a/backend/database/scripts/restore_db.sh b/backend/database/scripts/restore_db.sh new file mode 100644 index 0000000..83465d9 --- /dev/null +++ b/backend/database/scripts/restore_db.sh @@ -0,0 +1,74 @@ +#!/bin/bash +# database/scripts/restore.sh + +set -e + +# ============================================================================ +# CONFIGURATION +# ============================================================================ + +CONTAINER_NAME="${CONTAINER_NAME:-aurganize-postgres}" + +# Same path as backup.sh (HOST system) +BACKUP_DIR="${BACKUP_DIR:-$HOME/workspace/db_backup/aurganize_backups}" + +DB_NAME="${DB_NAME:-aurganize_dev}" +DB_USER="${DB_USER:-aurganize_backend_api}" + +# ============================================================================ +# CHECK ARGUMENTS +# ============================================================================ + +if [ -z "$1" ]; then + echo "Usage: $0 " + echo "" + echo "Available backups:" + ls -lh "${BACKUP_DIR}/${DB_NAME}"_*.sql.gz 2>/dev/null || echo "No backups found" + exit 1 +fi + +BACKUP_FILE="$1" + +if [ ! -f "$BACKUP_FILE" ]; then + echo "❌ Backup file not found: $BACKUP_FILE" + exit 1 +fi + +echo "===================================================================" +echo "PostgreSQL Restore (Docker)" +echo "===================================================================" +echo "⚠️ WARNING: This will ERASE all data in database \"${DB_NAME}\"!" +echo "Backup file: ${BACKUP_FILE}" +echo "" +read -p "Type 'yes' to continue: " CONFIRM + +if [ "$CONFIRM" != "yes" ]; then + echo "Aborted." + exit 0 +fi + +echo "" +echo "Dropping & recreating database inside Docker container..." + +# ============================================================================ +# DROP + CREATE DATABASE INSIDE DOCKER +# ============================================================================ + +docker exec -i "${CONTAINER_NAME}" psql -U postgres -c "DROP DATABASE IF EXISTS ${DB_NAME};" +docker exec -i "${CONTAINER_NAME}" psql -U postgres -c "CREATE DATABASE ${DB_NAME} OWNER ${DB_USER};" + +echo "✓ Database recreated" +echo "" + +# ============================================================================ +# RESTORE DATABASE +# ============================================================================ + +echo "Restoring backup into Docker container..." + +gunzip < "${BACKUP_FILE}" | docker exec -i "${CONTAINER_NAME}" psql -U "${DB_USER}" -d "${DB_NAME}" + +echo "" +echo "===================================================================" +echo "Restore Complete!" +echo "===================================================================" diff --git a/backend/database/scripts/test_ops.sh b/backend/database/scripts/test_ops.sh new file mode 100644 index 0000000..4e75125 --- /dev/null +++ b/backend/database/scripts/test_ops.sh @@ -0,0 +1,14 @@ +#!/bin/bash +set -e + +CONTAINER="aurganize-postgres" +DB_USER="aurganize_backend_api" +DB_NAME="aurganize_dev" +SEED_FILE="$(dirname "$0")/../tests/test_operations.sql" + +echo "Running development seeds..." + +docker exec -i "$CONTAINER" \ + psql -U "$DB_USER" -d "$DB_NAME" < "$SEED_FILE" + +echo "✓ Development seed data loaded successfully" diff --git a/backend/database/seeds/001_dev_data.sql b/backend/database/seeds/001_dev_data.sql new file mode 100644 index 0000000..dba5ea9 --- /dev/null +++ b/backend/database/seeds/001_dev_data.sql @@ -0,0 +1,224 @@ +-- ============================================================================= +-- DEVELOPMENT SEED DATA +-- ============================================================================= +-- WARNING: DO NOT RUN IN PRODUCTION! +-- ============================================================================= +-- ============================================================================= +-- Temporarily disable RLS inside the seed script +-- ============================================================================= +ALTER TABLE tenants DISABLE ROW LEVEL SECURITY; +ALTER TABLE users DISABLE ROW LEVEL SECURITY; +ALTER TABLE contracts DISABLE ROW LEVEL SECURITY; +ALTER TABLE deliverables DISABLE ROW LEVEL SECURITY; +ALTER TABLE milestones DISABLE ROW LEVEL SECURITY; +ALTER TABLE comments DISABLE ROW LEVEL SECURITY; +ALTER TABLE attachments DISABLE ROW LEVEL SECURITY; +ALTER TABLE audit_logs DISABLE ROW LEVEL SECURITY; +ALTER TABLE analytics_events DISABLE ROW LEVEL SECURITY; +ALTER TABLE notifications DISABLE ROW LEVEL SECURITY; +-- ============================================================================= + +BEGIN; + +-- ============================================================================= +-- Create test tenants +-- ============================================================================= + +-- Permanent tenant 1: ACME Corporation +INSERT INTO tenants (id, name, type) VALUES + ('10000000-0000-0000-0000-000000000001', 'ACME Corporation', 'permanent'); + +-- Permanent tenant 2: TechStart Inc +INSERT INTO tenants (id, name, type) VALUES + ('20000000-0000-0000-0000-000000000002', 'TechStart Inc', 'permanent'); + +-- Temporary tenant (project workspace) +INSERT INTO tenants (id, name, type, parent_tenant_id, expires_at) VALUES + ('30000000-0000-0000-0000-000000000003', + 'ACME-Website-Project', + 'temporary', + '10000000-0000-0000-0000-000000000001', + NOW() + INTERVAL '6 months'); + +-- ============================================================================= +-- Create test users +-- ============================================================================= + +-- ACME Corporation users +-- Password for all: "password123" (hashed with bcrypt cost 12) +INSERT INTO users (id, tenant_id, email, password_hash, name, role) VALUES + -- Admin + ('11000000-0000-0000-0000-000000000001', + '10000000-0000-0000-0000-000000000001', + 'admin@acme.com', + '$2a$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewY5GyYKU.PN5Hyu', + 'Alice Admin', + 'admin'), + + -- Vendor + ('11000000-0000-0000-0000-000000000002', + '10000000-0000-0000-0000-000000000001', + 'vendor@acme.com', + '$2a$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewY5GyYKU.PN5Hyu', + 'Bob Vendor', + 'vendor'), + + -- Consumer + ('11000000-0000-0000-0000-000000000003', + '10000000-0000-0000-0000-000000000001', + 'consumer@acme.com', + '$2a$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewY5GyYKU.PN5Hyu', + 'Charlie Consumer', + 'consumer'); + +-- TechStart Inc users +INSERT INTO users (id, tenant_id, email, password_hash, name, role) VALUES + ('21000000-0000-0000-0000-000000000001', + '20000000-0000-0000-0000-000000000002', + 'admin@techstart.com', + '$2a$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewY5GyYKU.PN5Hyu', + 'Diana Director', + 'admin'); + +-- ============================================================================= +-- Create test contracts +-- ============================================================================= + +INSERT INTO contracts ( + id, tenant_id, vendor_id, consumer_id, + title, description, status, + start_date, end_date, total_amount, created_by +) VALUES + -- Active contract + ('c1000000-0000-0000-0000-000000000001', + '10000000-0000-0000-0000-000000000001', + '11000000-0000-0000-0000-000000000002', + '11000000-0000-0000-0000-000000000003', + 'Website Redesign Project', + 'Complete overhaul of company website with modern design and responsive layout.', + 'active', + CURRENT_DATE - INTERVAL '1 month', + CURRENT_DATE + INTERVAL '5 months', + 50000.00, + '11000000-0000-0000-0000-000000000003'), + + -- Draft contract + ('c2000000-0000-0000-0000-000000000002', + '10000000-0000-0000-0000-000000000001', + '11000000-0000-0000-0000-000000000002', + '11000000-0000-0000-0000-000000000003', + 'Mobile App Development', + 'Native mobile application for iOS and Android platforms.', + 'draft', + CURRENT_DATE + INTERVAL '1 month', + CURRENT_DATE + INTERVAL '7 months', + 75000.00, + '11000000-0000-0000-0000-000000000003'); + +-- ============================================================================= +-- Create test deliverables +-- ============================================================================= + +INSERT INTO deliverables ( + id, tenant_id, contract_id, + title, description, sequence_number, status, deadline +) VALUES + -- Website project deliverables + ('d1000000-0000-0000-0000-000000000001', + '10000000-0000-0000-0000-000000000001', + 'c1000000-0000-0000-0000-000000000001', + 'Homepage Design', + 'Design mockups for the homepage including desktop and mobile views.', + 1, + 'approved', + CURRENT_DATE - INTERVAL '2 weeks'), + + ('d2000000-0000-0000-0000-000000000002', + '10000000-0000-0000-0000-000000000001', + 'c1000000-0000-0000-0000-000000000001', + 'Backend API Development', + 'RESTful API for content management and user authentication.', + 2, + 'in_progress', + CURRENT_DATE + INTERVAL '1 month'), + + ('d3000000-0000-0000-0000-000000000003', + '10000000-0000-0000-0000-000000000001', + 'c1000000-0000-0000-0000-000000000001', + 'Frontend Implementation', + 'React-based frontend with responsive design.', + 3, + 'pending', + CURRENT_DATE + INTERVAL '2 months'); + +-- ============================================================================= +-- Create test milestones +-- ============================================================================= + +INSERT INTO milestones ( + id, tenant_id, deliverable_id, + title, type, condition_value, amount, status +) VALUES + -- Homepage milestones + ('10000000-0000-4000-8000-000000000101', + '10000000-0000-0000-0000-000000000001', + 'd1000000-0000-0000-0000-000000000001', + 'Design approval', + 'fixed_date', + (CURRENT_DATE - INTERVAL '2 weeks')::TEXT, + 5000.00, + 'completed'), + + -- Backend milestones + ('20000000-0000-4000-8000-000000000102', + '10000000-0000-0000-0000-000000000001', + 'd2000000-0000-0000-0000-000000000002', + 'API endpoints complete', + 'duration_from_start', + '30', + 15000.00, + 'in_progress'); + +-- ============================================================================= +-- Create test comments +-- ============================================================================= + +INSERT INTO comments ( + id, tenant_id, entity_type, entity_id, + content, user_id +) VALUES + ('30000000-0000-4000-8000-000000000201', + '10000000-0000-0000-0000-000000000001', + 'contract', + 'c1000000-0000-0000-0000-000000000001', + 'Looking forward to starting this project!', + '11000000-0000-0000-0000-000000000003'), + + ('30000000-0000-4000-8000-000000000202', + '10000000-0000-0000-0000-000000000001', + 'deliverable', + 'd1000000-0000-0000-0000-000000000001', + 'Great work on the designs! Approved.', + '11000000-0000-0000-0000-000000000003'); + +COMMIT; + + + + +-- ============================================================================= +-- Re-enable RLS after the seed script +-- ============================================================================= + +ALTER TABLE tenants ENABLE ROW LEVEL SECURITY; +ALTER TABLE users ENABLE ROW LEVEL SECURITY; +ALTER TABLE contracts ENABLE ROW LEVEL SECURITY; +ALTER TABLE deliverables ENABLE ROW LEVEL SECURITY; +ALTER TABLE milestones ENABLE ROW LEVEL SECURITY; +ALTER TABLE comments ENABLE ROW LEVEL SECURITY; +ALTER TABLE attachments ENABLE ROW LEVEL SECURITY; +ALTER TABLE audit_logs ENABLE ROW LEVEL SECURITY; +ALTER TABLE analytics_events ENABLE ROW LEVEL SECURITY; +ALTER TABLE notifications ENABLE ROW LEVEL SECURITY; + +-- ============================================================================= diff --git a/backend/database/tests/health_check.sql b/backend/database/tests/health_check.sql new file mode 100644 index 0000000..f06e38f --- /dev/null +++ b/backend/database/tests/health_check.sql @@ -0,0 +1,70 @@ +-- database/scripts/health_check.sql + +\echo '=================================================================' +\echo 'PostgreSQL Health Check' +\echo '=================================================================' + +-- Database size +\echo '\nDatabase Sizes:' +SELECT + datname as database, + pg_size_pretty(pg_database_size(datname)) as size +FROM pg_database +WHERE datname LIKE 'aurganize%' +ORDER BY pg_database_size(datname) DESC; + +-- Table sizes +\echo '\nTop 10 Largest Tables:' +SELECT + schemaname, + tablename, + pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) as size +FROM pg_tables +WHERE schemaname = 'public' +ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC +LIMIT 10; + +-- Active connections +\echo '\nActive Connections:' +SELECT + count(*) as connections, + state +FROM pg_stat_activity +WHERE datname LIKE 'aurganize%' +GROUP BY state; + +-- Slow queries (if any) +\echo '\nSlow Queries (> 1 second):' +SELECT + pid, + now() - query_start as duration, + state, + substring(query, 1, 60) as query +FROM pg_stat_activity +WHERE state = 'active' + AND now() - query_start > interval '1 second' +ORDER BY duration DESC; + +-- Cache hit ratio (should be > 99%) +\echo '\nCache Hit Ratio:' +SELECT + sum(heap_blks_hit) / (sum(heap_blks_hit) + sum(heap_blks_read)) * 100 + as cache_hit_ratio +FROM pg_statio_user_tables; + +-- Index usage +\echo '\nUnused Indexes:' +SELECT + schemaname, + tablename, + indexname, + idx_scan as index_scans +FROM pg_stat_user_indexes +WHERE idx_scan = 0 + AND indexname NOT LIKE '%_pkey' +ORDER BY pg_relation_size(indexrelid) DESC +LIMIT 10; + +\echo '\n=================================================================' +\echo 'Health Check Complete' +\echo '=================================================================' \ No newline at end of file diff --git a/backend/database/tests/test_operations.sql b/backend/database/tests/test_operations.sql new file mode 100644 index 0000000..5c61c4b --- /dev/null +++ b/backend/database/tests/test_operations.sql @@ -0,0 +1,53 @@ +-- ============================================================================= +-- DATABASE OPERATIONS TEST SUITE +-- ============================================================================= + +\echo '=================================================================' +\echo 'Testing Basic Operations' +\echo '=================================================================' + +-- Set tenant context +SELECT set_tenant_context('10000000-0000-0000-0000-000000000001'::UUID); + +-- Test 1: Query contracts (should see only ACME contracts) +\echo '\n[Test 1] Query contracts for tenant...' +SELECT COUNT(*) as contract_count FROM contracts; +-- Expected: 2 + +-- Test 2: Query with joins +\echo '\n[Test 2] Query contracts with vendor/consumer...' +SELECT + c.title, + v.name as vendor_name, + con.name as consumer_name +FROM contracts c +JOIN users v ON c.vendor_id = v.id +JOIN users con ON c.consumer_id = con.id; +-- Expected: 2 rows + +-- Test 3: Full-text search +\echo '\n[Test 3] Search contracts...' +SELECT title +FROM contracts +WHERE to_tsvector('english', title || ' ' || COALESCE(description, '')) + @@ to_tsquery('english', 'website'); +-- Expected: 1 row (Website Redesign) + +-- Test 4: Test RLS isolation +\echo '\n[Test 4] Switch to different tenant...' +SELECT set_tenant_context('20000000-0000-0000-0000-000000000002'::UUID); +SELECT COUNT(*) FROM contracts; +-- Expected: 0 (different tenant) + +-- Test 5: Trigger test (updated_at) +\echo '\n[Test 5] Test updated_at trigger...' +SELECT set_tenant_context('10000000-0000-0000-0000-000000000001'::UUID); +UPDATE contracts +SET description = description || ' (updated)' +WHERE id = 'c1000000-0000-0000-0000-000000000001' +RETURNING title, updated_at > created_at as was_updated; +-- Expected: was_updated = true + +\echo '\n=================================================================' +\echo 'All Tests Complete!' +\echo '=================================================================' \ No newline at end of file diff --git a/infrastructure/docker/docker-compose.yml b/infrastructure/docker/docker-compose.yml new file mode 100644 index 0000000..8a1940f --- /dev/null +++ b/infrastructure/docker/docker-compose.yml @@ -0,0 +1,25 @@ +version: '3.8' + +services: + postgres: + image: postgres:14-alpine + container_name: aurganize-postgres + restart: always + environment: + # Superuser credentials (for initialization only) + POSTGRES_USER: postgres + POSTGRES_PASSWORD: "dev_pass_aurganize@v6.2" + POSTGRES_INITDB_ARGS: "--encoding=UTF-8 --lc-collate=en_US.UTF-8 --lc-ctype=en_US.UTF-8" + ports: + - "5432:5432" + volumes: + - postgres_data:/var/lib/postgresql/data + - ./init-scripts:/docker-entrypoint-initdb.d + healthcheck: + test: ["CMD-SHELL", "pg_isready -U postgres"] + interval: 10s + timeout: 5s + retries: 5 + +volumes: + postgres_data: \ No newline at end of file diff --git a/infrastructure/docker/init-scripts/01-create-users.sql b/infrastructure/docker/init-scripts/01-create-users.sql new file mode 100644 index 0000000..0505bff --- /dev/null +++ b/infrastructure/docker/init-scripts/01-create-users.sql @@ -0,0 +1,73 @@ +-- ========================================== +-- 01: CREATE APPLICATION USERS +-- ========================================== +-- This script creates PostgreSQL users for the application +-- Runs as: postgres (superuser) + +\echo '👤 Creating application users...' + +-- ========================================== +-- BACKEND API USER (Primary Application Role) +-- ========================================== +DO $$ +BEGIN + IF NOT EXISTS (SELECT FROM pg_roles WHERE rolname = 'aurganize_backend_api') THEN + CREATE USER aurganize_backend_api WITH + PASSWORD 'dev_backend_pass_v6.2' -- CHANGE IN PRODUCTION! + LOGIN + NOSUPERUSER + NOCREATEDB + NOCREATEROLE + NOREPLICATION + CONNECTION LIMIT 50; + + RAISE NOTICE '✅ User aurganize_backend_api created'; + RAISE NOTICE '⚠️ DEFAULT PASSWORD SET - CHANGE IN PRODUCTION!'; + ELSE + RAISE NOTICE '⚠️ User aurganize_backend_api already exists'; + END IF; +END +$$; + +-- ========================================== +-- READ-ONLY USER (Analytics/Reporting) +-- ========================================== +DO $$ +BEGIN + IF NOT EXISTS (SELECT FROM pg_roles WHERE rolname = 'aurganize_readonly') THEN + CREATE USER aurganize_readonly WITH + PASSWORD 'dev_readonly_pass_v6.2' -- CHANGE IN PRODUCTION! + LOGIN + NOSUPERUSER + NOCREATEDB + NOCREATEROLE + NOREPLICATION + CONNECTION LIMIT 10; + + RAISE NOTICE '✅ User aurganize_readonly created'; + ELSE + RAISE NOTICE '⚠️ User aurganize_readonly already exists'; + END IF; +END +$$; + +-- ========================================== +-- VERIFY USERS CREATED +-- ========================================== +\echo '' +\echo '📋 Verifying users...' +SELECT + rolname AS username, + rolcanlogin AS can_login, + rolconnlimit AS connection_limit, + CASE + WHEN rolsuper THEN 'superuser' + ELSE 'regular user' + END AS user_type +FROM pg_roles +WHERE rolname IN ('aurganize_backend_api', 'aurganize_readonly') +ORDER BY rolname; + +\echo '' +\echo '✅ Users created successfully' +\echo '' \ No newline at end of file diff --git a/infrastructure/docker/init-scripts/02-create-databases.sql b/infrastructure/docker/init-scripts/02-create-databases.sql new file mode 100644 index 0000000..7bf61ed --- /dev/null +++ b/infrastructure/docker/init-scripts/02-create-databases.sql @@ -0,0 +1,186 @@ +-- ========================================== +-- 02: CREATE DATABASES +-- ========================================== +-- This script creates development, staging, and production databases +-- Runs as: postgres (superuser) + +\echo '🗄️ Creating databases...' + +-- ========================================== +-- DEVELOPMENT DATABASE +-- ========================================== +CREATE DATABASE aurganize_dev + WITH + OWNER = aurganize_backend_api + ENCODING = 'UTF8' + LC_COLLATE = 'en_US.UTF-8' + LC_CTYPE = 'en_US.UTF-8' + TABLESPACE = pg_default + CONNECTION LIMIT = 50 + TEMPLATE = template0; + +COMMENT ON DATABASE aurganize_dev IS 'Aurganize V6.2 - Development Database'; + +\echo '✅ Database aurganize_dev created' + +-- ========================================== +-- STAGING DATABASE +-- ========================================== +CREATE DATABASE aurganize_staging + WITH + OWNER = aurganize_backend_api + ENCODING = 'UTF8' + LC_COLLATE = 'en_US.UTF-8' + LC_CTYPE = 'en_US.UTF-8' + TABLESPACE = pg_default + CONNECTION LIMIT = 50 + TEMPLATE = template0; + +COMMENT ON DATABASE aurganize_staging IS 'Aurganize V6.2 - Staging Database'; + +\echo '✅ Database aurganize_staging created' + +-- ========================================== +-- PRODUCTION DATABASE +-- ========================================== +CREATE DATABASE aurganize_prod + WITH + OWNER = aurganize_backend_api + ENCODING = 'UTF8' + LC_COLLATE = 'en_US.UTF-8' + LC_CTYPE = 'en_US.UTF-8' + TABLESPACE = pg_default + CONNECTION LIMIT = 100 + TEMPLATE = template0; + +COMMENT ON DATABASE aurganize_prod IS 'Aurganize V6.2 - Production Database'; + +\echo '✅ Database aurganize_prod created' + +-- ========================================== +-- GRANT PERMISSIONS - DEVELOPMENT DATABASE +-- ========================================== +\echo '' +\echo '🔐 Configuring permissions for aurganize_dev...' + +\c aurganize_dev + +-- Grant schema usage +GRANT USAGE ON SCHEMA public TO aurganize_backend_api; + +-- Grant all permissions on tables (current and future) +GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON TABLES TO aurganize_backend_api; + +-- Grant sequence permissions (for auto-increment IDs) +GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON SEQUENCES TO aurganize_backend_api; + +-- Grant function execution +GRANT ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON FUNCTIONS TO aurganize_backend_api; + +-- Grant read-only access +GRANT CONNECT ON DATABASE aurganize_dev TO aurganize_readonly; +GRANT USAGE ON SCHEMA public TO aurganize_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO aurganize_readonly; + +-- Future tables +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT SELECT ON TABLES TO aurganize_readonly; + +\echo '✅ Permissions configured for aurganize_dev' + +-- ========================================== +-- GRANT PERMISSIONS - STAGING DATABASE +-- ========================================== +\echo '' +\echo '🔐 Configuring permissions for aurganize_staging...' + +\c aurganize_staging + +-- Grant schema usage +GRANT USAGE ON SCHEMA public TO aurganize_backend_api; + +-- Grant all permissions on tables (current and future) +GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON TABLES TO aurganize_backend_api; + +-- Grant sequence permissions +GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON SEQUENCES TO aurganize_backend_api; + +-- Grant function execution +GRANT ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON FUNCTIONS TO aurganize_backend_api; + +-- Grant read-only access +GRANT CONNECT ON DATABASE aurganize_staging TO aurganize_readonly; +GRANT USAGE ON SCHEMA public TO aurganize_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO aurganize_readonly; + +-- Future tables +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT SELECT ON TABLES TO aurganize_readonly; + +\echo '✅ Permissions configured for aurganize_staging' + +-- ========================================== +-- GRANT PERMISSIONS - PRODUCTION DATABASE +-- ========================================== +\echo '' +\echo '🔐 Configuring permissions for aurganize_prod...' + +\c aurganize_prod + +-- Grant schema usage +GRANT USAGE ON SCHEMA public TO aurganize_backend_api; + +-- Grant all permissions on tables (current and future) +GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON TABLES TO aurganize_backend_api; + +-- Grant sequence permissions +GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON SEQUENCES TO aurganize_backend_api; + +-- Grant function execution +GRANT ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA public TO aurganize_backend_api; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT ALL PRIVILEGES ON FUNCTIONS TO aurganize_backend_api; + +-- Grant read-only access +GRANT CONNECT ON DATABASE aurganize_prod TO aurganize_readonly; +GRANT USAGE ON SCHEMA public TO aurganize_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO aurganize_readonly; + +-- Future tables +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT SELECT ON TABLES TO aurganize_readonly; + +\echo '✅ Permissions configured for aurganize_prod' + +-- ========================================== +-- SUMMARY +-- ========================================== +\echo '' +\echo '==========================================' +\echo '✅ All databases created and configured!' +\echo '==========================================' +\echo '' +\echo 'Databases:' +\echo ' - aurganize_dev (development)' +\echo ' - aurganize_staging (staging)' +\echo ' - aurganize_prod (production)' +\echo '' +\echo 'Owners: aurganize_backend_api' +\echo 'Read-only access: aurganize_readonly' +\echo '' \ No newline at end of file diff --git a/infrastructure/docker/init-scripts/03-install-extenstions.sql b/infrastructure/docker/init-scripts/03-install-extenstions.sql new file mode 100644 index 0000000..4d8b9b0 --- /dev/null +++ b/infrastructure/docker/init-scripts/03-install-extenstions.sql @@ -0,0 +1,112 @@ +-- ========================================== +-- 03: INSTALL POSTGRESQL EXTENSIONS +-- ========================================== +-- This script installs required extensions on all databases +-- Runs as: postgres (superuser) + +\echo '🔌 Installing PostgreSQL extensions...' + +-- ========================================== +-- DEVELOPMENT DATABASE +-- ========================================== +\c aurganize_dev + +\echo '' +\echo '📦 Installing extensions on aurganize_dev...' + +-- UUID Generation (Required) +CREATE EXTENSION IF NOT EXISTS "uuid-ossp" + WITH SCHEMA public + VERSION "1.1"; + +COMMENT ON EXTENSION "uuid-ossp" IS 'Generate universally unique identifiers (UUIDs)'; + +\echo ' ✅ uuid-ossp installed' + +-- Trigram Matching (For Fuzzy Search) +CREATE EXTENSION IF NOT EXISTS "pg_trgm" + WITH SCHEMA public; + +COMMENT ON EXTENSION "pg_trgm" IS 'Text similarity measurement and index searching based on trigrams'; + +\echo ' ✅ pg_trgm installed' + +-- BTree GIN Index (For Complex Queries) +CREATE EXTENSION IF NOT EXISTS "btree_gin" + WITH SCHEMA public; + +COMMENT ON EXTENSION "btree_gin" IS 'Support for indexing common datatypes in GIN'; + +\echo ' ✅ btree_gin installed' + +-- Test UUID generation +DO $$ +DECLARE + test_uuid UUID; +BEGIN + test_uuid := uuid_generate_v4(); + RAISE NOTICE ' 🧪 Test UUID generated: %', test_uuid; +END $$; + +-- Test trigram similarity +DO $$ +DECLARE + similarity_score FLOAT; +BEGIN + similarity_score := similarity('PostgreSQL', 'Postgres'); + RAISE NOTICE ' 🧪 Trigram similarity test: %', similarity_score; +END $$; + +-- ========================================== +-- STAGING DATABASE +-- ========================================== +\c aurganize_staging + +\echo '' +\echo '📦 Installing extensions on aurganize_staging...' + +CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA public VERSION "1.1"; +CREATE EXTENSION IF NOT EXISTS "pg_trgm" WITH SCHEMA public; +CREATE EXTENSION IF NOT EXISTS "btree_gin" WITH SCHEMA public; + +\echo ' ✅ All extensions installed on staging' + +-- ========================================== +-- PRODUCTION DATABASE +-- ========================================== +\c aurganize_prod + +\echo '' +\echo '📦 Installing extensions on aurganize_prod...' + +CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA public VERSION "1.1"; +CREATE EXTENSION IF NOT EXISTS "pg_trgm" WITH SCHEMA public; +CREATE EXTENSION IF NOT EXISTS "btree_gin" WITH SCHEMA public; + +\echo ' ✅ All extensions installed on production' + +-- ========================================== +-- SUMMARY +-- ========================================== +\echo '' +\echo '==========================================' +\echo '✅ Extensions installed successfully!' +\echo '==========================================' +\echo '' + +-- List all extensions (on dev database) +\c aurganize_dev + +SELECT + e.extname AS "Extension", + e.extversion AS "Version", + n.nspname AS "Schema" +FROM + pg_extension e + JOIN pg_namespace n ON e.extnamespace = n.oid +WHERE + e.extname IN ('uuid-ossp', 'pg_trgm', 'btree_gin') +ORDER BY + e.extname; + +\echo '' \ No newline at end of file diff --git a/infrastructure/docker/init-scripts/04-setup-rls.sql b/infrastructure/docker/init-scripts/04-setup-rls.sql new file mode 100644 index 0000000..f72b51e --- /dev/null +++ b/infrastructure/docker/init-scripts/04-setup-rls.sql @@ -0,0 +1,397 @@ +-- ========================================== +-- 04: ROW-LEVEL SECURITY HELPER FUNCTIONS +-- ========================================== +-- This script creates utility functions for RLS management +-- Runs as: postgres (superuser) + +\echo '🔒 Creating RLS helper functions...' + +-- ========================================== +-- DEVELOPMENT DATABASE +-- ========================================== +\c aurganize_dev + +\echo '' +\echo '🔧 Creating helper functions on aurganize_dev...' + +-- ========================================== +-- FUNCTION: set_tenant_context +-- Purpose: Sets the current tenant ID in session context +-- ========================================== +CREATE OR REPLACE FUNCTION set_tenant_context(p_tenant_id UUID) +RETURNS VOID AS $$ +BEGIN + -- Set session variable with tenant ID + -- set_config(setting_name, new_value, is_local) + -- setting_name: 'app.current_tenant_id' (custom variable) + -- new_value: p_tenant_id as TEXT + -- is_local: false = lasts until transaction end + -- true = lasts until statement end + PERFORM set_config('app.current_tenant_id', p_tenant_id::TEXT, false); + + -- Log for debugging (only visible with client_min_messages = DEBUG) + RAISE DEBUG 'Tenant context set to: %', p_tenant_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Grant execute to application user +GRANT EXECUTE ON FUNCTION set_tenant_context(UUID) TO aurganize_backend_api; + +-- Add comment +COMMENT ON FUNCTION set_tenant_context(UUID) IS + 'Sets the current tenant context for Row-Level Security filtering. Call at the beginning of each request.'; + +\echo ' ✅ Function set_tenant_context created' + +-- ========================================== +-- FUNCTION: get_current_tenant +-- Purpose: Returns the current tenant ID from session context +-- ========================================== +CREATE OR REPLACE FUNCTION get_current_tenant() +RETURNS UUID AS $$ +BEGIN + -- current_setting(setting_name, missing_ok) + -- setting_name: 'app.current_tenant_id' + -- missing_ok: true = return NULL if not set (don't error) + RETURN current_setting('app.current_tenant_id', true)::UUID; +EXCEPTION + WHEN OTHERS THEN + -- If conversion fails or any error, return NULL + RETURN NULL; +END; +$$ LANGUAGE plpgsql STABLE SECURITY DEFINER; + +-- Grant execute to application user +GRANT EXECUTE ON FUNCTION get_current_tenant() TO aurganize_backend_api; + +-- Add comment +COMMENT ON FUNCTION get_current_tenant() IS + 'Returns the current tenant ID from session context. Returns NULL if not set.'; + +\echo ' ✅ Function get_current_tenant created' + +-- ========================================== +-- FUNCTION: create_tenant_isolation_policy +-- Purpose: Creates standard RLS policy on a table +-- ========================================== +CREATE OR REPLACE FUNCTION create_tenant_isolation_policy(p_table_name TEXT) +RETURNS VOID AS $$ +DECLARE + v_policy_name TEXT; +BEGIN + -- Generate policy name + v_policy_name := p_table_name || '_tenant_isolation'; + + -- Enable RLS on table + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + + -- Drop policy if exists (for re-running) + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + + -- Create policy + -- USING clause: Controls which rows are visible for SELECT/UPDATE/DELETE + -- WITH CHECK clause: Controls which rows can be inserted/updated + EXECUTE format(' + CREATE POLICY %I ON %I + USING (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID) + WITH CHECK (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID) + ', v_policy_name, p_table_name); + + RAISE NOTICE '✅ Created RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; + +-- Grant execute to application user +GRANT EXECUTE ON FUNCTION create_tenant_isolation_policy(TEXT) TO aurganize_backend_api; + +-- Add comment +COMMENT ON FUNCTION create_tenant_isolation_policy(TEXT) IS + 'Creates a standard tenant isolation RLS policy on the specified table. Table must have a tenant_id column.'; + +\echo ' ✅ Function create_tenant_isolation_policy created' + +-- ========================================== +-- FUNCTION: create_contract_participant_policy +-- Purpose: Creates RLS policy for contract-based access +-- ========================================== +CREATE OR REPLACE FUNCTION create_contract_participant_policy(p_table_name TEXT) +RETURNS VOID AS $$ +DECLARE + v_policy_name TEXT; +BEGIN + -- Generate policy name + v_policy_name := p_table_name || '_contract_access'; + + -- Enable RLS on table + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + + -- Drop policy if exists + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + + -- Create policy for contract-related tables + -- Allows access if tenant is vendor OR consumer in the contract + EXECUTE format(' + CREATE POLICY %I ON %I + USING ( + EXISTS ( + SELECT 1 FROM contracts + WHERE contracts.id = %I.contract_id + AND ( + contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID + OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID + ) + ) + ) + WITH CHECK ( + EXISTS ( + SELECT 1 FROM contracts + WHERE contracts.id = %I.contract_id + AND ( + contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID + OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID + ) + ) + ) + ', v_policy_name, p_table_name, p_table_name, p_table_name); + + RAISE NOTICE '✅ Created contract-based RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; + +-- Grant execute to application user +GRANT EXECUTE ON FUNCTION create_contract_participant_policy(TEXT) TO aurganize_backend_api; + +-- Add comment +COMMENT ON FUNCTION create_contract_participant_policy(TEXT) IS + 'Creates an RLS policy for contract-related tables. Grants access if tenant is vendor or consumer. Table must have a contract_id column.'; + +\echo ' ✅ Function create_contract_participant_policy created' + + +-- ========================================== +-- FUNCTION: audit_rls_status +-- Purpose: Audit and report RLS status across all tables +-- ========================================== +CREATE OR REPLACE FUNCTION audit_rls_status() +RETURNS TABLE ( + table_name TEXT, + rls_enabled BOOLEAN, + policy_count BIGINT, + status TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + t.tablename::TEXT AS table_name, + t.rowsecurity AS rls_enabled, + COUNT(p.policyname) AS policy_count, + CASE + WHEN t.rowsecurity AND COUNT(p.policyname) > 0 THEN '✓ Protected' + WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN '⚠ Enabled but no policies' + ELSE '✗ Not protected' + END AS status + FROM pg_tables t + LEFT JOIN pg_policies p + ON p.tablename = t.tablename + AND p.schemaname = t.schemaname + WHERE t.schemaname = 'public' + AND t.tablename NOT LIKE 'pg_%' -- Exclude PostgreSQL system tables + AND t.tablename NOT LIKE 'sql_%' -- Exclude SQL standard tables + GROUP BY t.schemaname, t.tablename, t.rowsecurity + ORDER BY + CASE + WHEN NOT t.rowsecurity THEN 1 -- Not protected first + WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN 2 -- Enabled but no policies + ELSE 3 -- Protected + END, + t.tablename; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Grant execute to application user and readonly user +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_backend_api; +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_readonly; + +-- Add comment +COMMENT ON FUNCTION audit_rls_status() IS + 'Audits and reports Row-Level Security status for all tables in the public schema. Returns table name, RLS enabled status, policy count, and protection status.'; + +\echo ' ✅ Function audit_rls_status created' + + +-- ========================================== +-- STAGING DATABASE +-- ========================================== +\c aurganize_staging + +\echo '' +\echo '🔧 Creating helper functions on aurganize_staging...' + +CREATE OR REPLACE FUNCTION set_tenant_context(p_tenant_id UUID) RETURNS VOID AS $$ +BEGIN + PERFORM set_config('app.current_tenant_id', p_tenant_id::TEXT, false); + RAISE DEBUG 'Tenant context set to: %', p_tenant_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION set_tenant_context(UUID) TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION get_current_tenant() RETURNS UUID AS $$ +BEGIN + RETURN current_setting('app.current_tenant_id', true)::UUID; +EXCEPTION WHEN OTHERS THEN RETURN NULL; +END; +$$ LANGUAGE plpgsql STABLE SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION get_current_tenant() TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION create_tenant_isolation_policy(p_table_name TEXT) RETURNS VOID AS $$ +DECLARE v_policy_name TEXT; +BEGIN + v_policy_name := p_table_name || '_tenant_isolation'; + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + EXECUTE format('CREATE POLICY %I ON %I USING (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID) WITH CHECK (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID)', v_policy_name, p_table_name); + RAISE NOTICE '✅ Created RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; +GRANT EXECUTE ON FUNCTION create_tenant_isolation_policy(TEXT) TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION create_contract_participant_policy(p_table_name TEXT) RETURNS VOID AS $$ +DECLARE v_policy_name TEXT; +BEGIN + v_policy_name := p_table_name || '_contract_access'; + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + EXECUTE format('CREATE POLICY %I ON %I USING (EXISTS (SELECT 1 FROM contracts WHERE contracts.id = %I.contract_id AND (contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID))) WITH CHECK (EXISTS (SELECT 1 FROM contracts WHERE contracts.id = %I.contract_id AND (contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID)))', v_policy_name, p_table_name, p_table_name, p_table_name); + RAISE NOTICE '✅ Created contract-based RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; +GRANT EXECUTE ON FUNCTION create_contract_participant_policy(TEXT) TO aurganize_backend_api; + +\echo ' ✅ All helper functions created on staging' + +-- ========================================== +-- FUNCTION: audit_rls_status +-- Purpose: Audit and report RLS status across all tables +-- ========================================== +CREATE OR REPLACE FUNCTION audit_rls_status() +RETURNS TABLE (table_name TEXT, rls_enabled BOOLEAN, policy_count BIGINT, status TEXT) AS $$ +BEGIN + RETURN QUERY + SELECT + t.tablename::TEXT, + t.rowsecurity, + COUNT(p.policyname), + CASE + WHEN t.rowsecurity AND COUNT(p.policyname) > 0 THEN '✓ Protected' + WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN '⚠ Enabled but no policies' + ELSE '✗ Not protected' + END + FROM pg_tables t + LEFT JOIN pg_policies p ON p.tablename = t.tablename AND p.schemaname = t.schemaname + WHERE t.schemaname = 'public' AND t.tablename NOT LIKE 'pg_%' AND t.tablename NOT LIKE 'sql_%' + GROUP BY t.schemaname, t.tablename, t.rowsecurity + ORDER BY CASE WHEN NOT t.rowsecurity THEN 1 WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN 2 ELSE 3 END, t.tablename; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_backend_api; +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_readonly; +COMMENT ON FUNCTION audit_rls_status() IS 'Audits and reports Row-Level Security status for all tables.'; + + +-- ========================================== +-- PRODUCTION DATABASE +-- ========================================== +\c aurganize_prod + +\echo '' +\echo '🔧 Creating helper functions on aurganize_prod...' + +CREATE OR REPLACE FUNCTION set_tenant_context(p_tenant_id UUID) RETURNS VOID AS $$ +BEGIN + PERFORM set_config('app.current_tenant_id', p_tenant_id::TEXT, false); + RAISE DEBUG 'Tenant context set to: %', p_tenant_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION set_tenant_context(UUID) TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION get_current_tenant() RETURNS UUID AS $$ +BEGIN + RETURN current_setting('app.current_tenant_id', true)::UUID; +EXCEPTION WHEN OTHERS THEN RETURN NULL; +END; +$$ LANGUAGE plpgsql STABLE SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION get_current_tenant() TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION create_tenant_isolation_policy(p_table_name TEXT) RETURNS VOID AS $$ +DECLARE v_policy_name TEXT; +BEGIN + v_policy_name := p_table_name || '_tenant_isolation'; + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + EXECUTE format('CREATE POLICY %I ON %I USING (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID) WITH CHECK (tenant_id = current_setting(''app.current_tenant_id'', true)::UUID)', v_policy_name, p_table_name); + RAISE NOTICE '✅ Created RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; +GRANT EXECUTE ON FUNCTION create_tenant_isolation_policy(TEXT) TO aurganize_backend_api; + +CREATE OR REPLACE FUNCTION create_contract_participant_policy(p_table_name TEXT) RETURNS VOID AS $$ +DECLARE v_policy_name TEXT; +BEGIN + v_policy_name := p_table_name || '_contract_access'; + EXECUTE format('ALTER TABLE %I ENABLE ROW LEVEL SECURITY', p_table_name); + EXECUTE format('DROP POLICY IF EXISTS %I ON %I', v_policy_name, p_table_name); + EXECUTE format('CREATE POLICY %I ON %I USING (EXISTS (SELECT 1 FROM contracts WHERE contracts.id = %I.contract_id AND (contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID))) WITH CHECK (EXISTS (SELECT 1 FROM contracts WHERE contracts.id = %I.contract_id AND (contracts.vendor_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID OR contracts.consumer_tenant_id = current_setting(''app.current_tenant_id'', true)::UUID)))', v_policy_name, p_table_name, p_table_name, p_table_name); + RAISE NOTICE '✅ Created contract-based RLS policy: % on table: %', v_policy_name, p_table_name; +END; +$$ LANGUAGE plpgsql; +GRANT EXECUTE ON FUNCTION create_contract_participant_policy(TEXT) TO aurganize_backend_api; + +\echo ' ✅ All helper functions created on production' + +-- ========================================== +-- FUNCTION: audit_rls_status +-- Purpose: Audit and report RLS status across all tables +-- ========================================== +CREATE OR REPLACE FUNCTION audit_rls_status() +RETURNS TABLE (table_name TEXT, rls_enabled BOOLEAN, policy_count BIGINT, status TEXT) AS $$ +BEGIN + RETURN QUERY + SELECT + t.tablename::TEXT, + t.rowsecurity, + COUNT(p.policyname), + CASE + WHEN t.rowsecurity AND COUNT(p.policyname) > 0 THEN '✓ Protected' + WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN '⚠ Enabled but no policies' + ELSE '✗ Not protected' + END + FROM pg_tables t + LEFT JOIN pg_policies p ON p.tablename = t.tablename AND p.schemaname = t.schemaname + WHERE t.schemaname = 'public' AND t.tablename NOT LIKE 'pg_%' AND t.tablename NOT LIKE 'sql_%' + GROUP BY t.schemaname, t.tablename, t.rowsecurity + ORDER BY CASE WHEN NOT t.rowsecurity THEN 1 WHEN t.rowsecurity AND COUNT(p.policyname) = 0 THEN 2 ELSE 3 END, t.tablename; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_backend_api; +GRANT EXECUTE ON FUNCTION audit_rls_status() TO aurganize_readonly; +COMMENT ON FUNCTION audit_rls_status() IS 'Audits and reports Row-Level Security status for all tables.'; + + +-- ========================================== +-- SUMMARY +-- ========================================== +\echo '' +\echo '==========================================' +\echo '✅ RLS helper functions created!' +\echo '==========================================' +\echo '' +\echo 'Functions created on all databases:' +\echo ' - set_tenant_context(UUID) Set current tenant' +\echo ' - get_current_tenant() Get current tenant' +\echo ' - create_tenant_isolation_policy(TEXT) Apply RLS to table' +\echo ' - create_contract_participant_policy(TEXT) Contract-based RLS' +\echo '' +\echo 'Usage example:' +\echo ' SELECT set_tenant_context(''550e8400-e29b-41d4-a716-446655440000''::UUID);' +\echo ' SELECT create_tenant_isolation_policy(''users'');' +\echo '' \ No newline at end of file diff --git a/infrastructure/docker/init-scripts/05-test-rls.sql b/infrastructure/docker/init-scripts/05-test-rls.sql new file mode 100644 index 0000000..332df05 --- /dev/null +++ b/infrastructure/docker/init-scripts/05-test-rls.sql @@ -0,0 +1,212 @@ +-- ========================================== +-- 05: TEST ROW-LEVEL SECURITY (OPTIONAL) +-- ========================================== +-- This script tests RLS functionality +-- Comment out this file in production! +-- Runs as: postgres (superuser) + +\echo '' +\echo '⚠️ WARNING: This is a test script!' +\echo '⚠️ Remove or comment out for production!' +\echo '' +\echo '🧪 Testing Row-Level Security...' + +-- ========================================== +-- Connect to development database +-- ========================================== +\c aurganize_dev + +-- ========================================== +-- CREATE TEST TABLE +-- ========================================== +\echo '' +\echo '📋 Creating test table...' + +DROP TABLE IF EXISTS rls_test CASCADE; + +CREATE TABLE rls_test ( + id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + tenant_id UUID NOT NULL, + data TEXT +); + +\echo ' ✅ Table rls_test created' + +-- ========================================== +-- APPLY RLS POLICY +-- ========================================== +\echo '' +\echo '🔒 Applying RLS policy...' + +SELECT create_tenant_isolation_policy('rls_test'); + +\echo ' ✅ RLS policy applied' + +-- ========================================== +-- INSERT TEST DATA +-- ========================================== +\echo '' +\echo '📝 Inserting test data...' + +INSERT INTO rls_test (tenant_id, data) VALUES + ('550e8400-e29b-41d4-a716-446655440000', 'Tenant A - Record 1'), + ('550e8400-e29b-41d4-a716-446655440000', 'Tenant A - Record 2'), + ('660e8400-e29b-41d4-a716-446655440001', 'Tenant B - Record 1'), + ('660e8400-e29b-41d4-a716-446655440001', 'Tenant B - Record 2'); + +\echo ' ✅ Inserted 4 records (2 per tenant)' + +-- ========================================== +-- TEST AS SUPERUSER (Should see all) +-- ========================================== +\echo '' +\echo '👑 Testing as superuser (should see ALL records)...' + +SELECT COUNT(*) AS total_records FROM rls_test; + +\echo '' + +-- ========================================== +-- TEST AS APPLICATION USER +-- ========================================== +\echo '' +\echo '👤 Testing as application user...' +\echo '' + +-- Reconnect as application user +\c aurganize_dev aurganize_backend_api + +-- ========================================== +-- TEST 1: Set Tenant A Context +-- ========================================== +\echo '🔧 Test 1: Setting Tenant A context...' +SELECT set_tenant_context('550e8400-e29b-41d4-a716-446655440000'::UUID); + +\echo '📊 Querying (should see 2 Tenant A records only):' +SELECT id, tenant_id, data FROM rls_test ORDER BY data; + +\echo '' + +-- Verify current tenant +\echo '🔍 Current tenant:' +SELECT get_current_tenant() AS current_tenant; + +\echo '' + +-- ========================================== +-- TEST 2: Switch to Tenant B +-- ========================================== +\echo '🔧 Test 2: Switching to Tenant B context...' +SELECT set_tenant_context('660e8400-e29b-41d4-a716-446655440001'::UUID); + +\echo '📊 Querying (should see 2 Tenant B records only):' +SELECT id, tenant_id, data FROM rls_test ORDER BY data; + +\echo '' + +-- ========================================== +-- TEST 3: Try to Insert with Wrong Tenant ID +-- ========================================== +\echo '🧪 Test 3: Attempting to insert with WRONG tenant_id (should FAIL)...' + +DO $$ +BEGIN + INSERT INTO rls_test (tenant_id, data) + VALUES ('550e8400-e29b-41d4-a716-446655440000', 'Hacked!'); + + RAISE EXCEPTION 'ERROR: Insert succeeded when it should have failed!'; +EXCEPTION + WHEN others THEN + IF SQLERRM LIKE '%violates row-level security policy%' THEN + RAISE NOTICE ' ✅ PASS: Insert correctly blocked by RLS'; + ELSE + RAISE NOTICE ' ❌ FAIL: Unexpected error: %', SQLERRM; + END IF; +END; +$$; + +\echo '' + +-- ========================================== +-- TEST 4: Insert with Correct Tenant ID +-- ========================================== +\echo '🧪 Test 4: Inserting with CORRECT tenant_id (should SUCCEED)...' + +INSERT INTO rls_test (tenant_id, data) +VALUES ('660e8400-e29b-41d4-a716-446655440001', 'Valid insert'); + +\echo ' ✅ PASS: Insert succeeded' + +\echo '' +\echo '📊 Query again (should now see 3 Tenant B records):' +SELECT id, tenant_id, data FROM rls_test ORDER BY data; + +\echo '' + +-- ========================================== +-- TEST 5: Try to Update to Different Tenant +-- ========================================== +\echo '🧪 Test 5: Attempting to UPDATE to different tenant_id (should FAIL)...' + +DO $$ +BEGIN + UPDATE rls_test + SET tenant_id = '550e8400-e29b-41d4-a716-446655440000' + WHERE data = 'Valid insert'; + + RAISE EXCEPTION 'ERROR: Update succeeded when it should have failed!'; +EXCEPTION + WHEN others THEN + IF SQLERRM LIKE '%violates row-level security policy%' THEN + RAISE NOTICE ' ✅ PASS: Update correctly blocked by RLS'; + ELSE + RAISE NOTICE ' ❌ FAIL: Unexpected error: %', SQLERRM; + END IF; +END; +$$; + +\echo '' + +-- ========================================== +-- TEST 6: Try to See All Records +-- ========================================== +\echo '🧪 Test 6: Verifying data is still filtered...' +\echo '📊 Count (should still be 3 Tenant B records only):' + +SELECT COUNT(*) AS visible_records FROM rls_test; + +\echo '' + +-- ========================================== +-- CLEANUP +-- ========================================== +\echo '🧹 Cleaning up...' + +-- Reconnect as superuser +\c aurganize_dev postgres + +-- Drop test table +DROP TABLE IF EXISTS rls_test CASCADE; + +\echo ' ✅ Test table dropped' + +-- ========================================== +-- TEST SUMMARY +-- ========================================== +\echo '' +\echo '==========================================' +\echo '✅ RLS TESTING COMPLETE!' +\echo '==========================================' +\echo '' +\echo 'Test Results:' +\echo ' ✅ Tenant isolation works correctly' +\echo ' ✅ Cannot insert with wrong tenant_id' +\echo ' ✅ Can insert with correct tenant_id' +\echo ' ✅ Cannot update to different tenant_id' +\echo ' ✅ Queries are properly filtered' +\echo '' +\echo '🔒 Row-Level Security is functioning as expected!' +\echo '' +\echo '⚠️ REMINDER: Remove or comment out this test' +\echo ' script for production deployment!' +\echo '' \ No newline at end of file