-- ============================================================================= -- AURGANIZE V6.2 - INITIAL SCHEMA (MARKETPLACE ARCHITECTURE) -- ============================================================================= -- Migration: 000001_initial_schema -- Description: Creates core tables matching Go models exactly -- Author: Aurganize Team -- Date: 2025-12-11 -- Version: 2.0 (Marketplace Edition - Matching Go Models) -- ============================================================================= -- This migration establishes the foundational database schema for Aurganize V6.2, -- a B2B marketplace platform connecting vendors and consumers. -- -- Key Design Decisions: -- 1. Schema matches Go models EXACTLY (no mismatches) -- 2. Multi-tenancy WITHOUT strict RLS on tenants/users (marketplace discovery) -- 3. Collaboration-aware RLS on contracts (both vendor & consumer can access) -- 4. System role with BYPASSRLS for registration flow -- 5. Full-text search for marketplace discovery -- ============================================================================= -- ============================================================================= -- SECTION 1: EXTENSIONS -- ============================================================================= CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pg_trgm"; -- Fuzzy text search CREATE EXTENSION IF NOT EXISTS "btree_gin"; -- JSONB indexes CREATE EXTENSION IF NOT EXISTS "unaccent"; -- For slug generation -- ============================================================================= -- SECTION 2: CUSTOM ENUM TYPES -- ============================================================================= -- User roles for marketplace participants CREATE TYPE user_role AS ENUM ( 'admin', -- Platform administrator 'vendor', -- Service provider (interior designers, agencies, etc.) 'consumer', -- Service buyer (hotels, companies, etc.) 'project_manager' -- Project coordinator ); -- Contract lifecycle states CREATE TYPE contract_status AS ENUM ( 'draft', -- Being negotiated 'active', -- Work in progress 'completed', -- All deliverables approved 'cancelled' -- Terminated before completion ); -- Deliverable workflow states CREATE TYPE deliverable_status AS ENUM ( 'pending', -- Not yet started 'in_progress', -- Vendor working on it 'submitted', -- Awaiting consumer approval 'approved', -- Consumer accepted 'rejected' -- Needs rework ); -- Milestone scheduling types CREATE TYPE milestone_type AS ENUM ( 'fixed_date', -- Specific calendar date (e.g., "2025-12-31") 'duration_from_start', -- Days from contract start (e.g., "30") 'duration_from_previous' -- Days from previous milestone (e.g., "14") ); -- Milestone completion states CREATE TYPE milestone_status AS ENUM ( 'pending', -- Not yet eligible 'in_progress', -- Conditions being met 'completed' -- Fully satisfied ); -- ============================================================================= -- SECTION 3: TENANTS TABLE -- ============================================================================= -- Organizations in the marketplace (vendors and consumers) -- ✅ Matches Go model exactly -- ✅ NO strict RLS - discoverable for marketplace -- ============================================================================= CREATE TABLE tenants ( -- Identity id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(255) NOT NULL, slug VARCHAR(100) UNIQUE NOT NULL, -- Contact information (matches Go model) email VARCHAR(255), phone VARCHAR(50), website TEXT, -- Address (matches Go model) address_line1 VARCHAR(255), address_line2 VARCHAR(255), city VARCHAR(100), state VARCHAR(100), country VARCHAR(100), postal_code VARCHAR(20), -- Localization (matches Go model) timezone VARCHAR(50) NOT NULL DEFAULT 'UTC', currency VARCHAR(3) NOT NULL DEFAULT 'USD', locale VARCHAR(10) NOT NULL DEFAULT 'en-US', -- Subscription & billing (matches Go model) subscription_status VARCHAR(50) NOT NULL DEFAULT 'trial', subscription_plan VARCHAR(50) NOT NULL DEFAULT 'basic', subscription_expires_at TIMESTAMPTZ, trial_ends_at TIMESTAMPTZ, -- Limits (matches Go model) max_users INTEGER NOT NULL DEFAULT 10, max_contracts INTEGER NOT NULL DEFAULT 50, max_storage_mb INTEGER NOT NULL DEFAULT 5120, -- Status (matches Go model - NOT is_active) status VARCHAR(50) NOT NULL DEFAULT 'active', -- Audit fields (matches Go model) created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, -- Constraints CONSTRAINT chk_tenant_subscription_status CHECK ( subscription_status IN ('trial', 'active', 'cancelled', 'expired', 'suspended') ), CONSTRAINT chk_tenant_subscription_plan CHECK ( subscription_plan IN ('basic', 'professional', 'enterprise') ), CONSTRAINT chk_tenant_status CHECK ( status IN ('active', 'inactive', 'suspended', 'deleted') ) ); -- Performance indexes CREATE INDEX idx_tenants_slug ON tenants(slug); CREATE INDEX idx_tenants_status ON tenants(status) WHERE status = 'active'; CREATE INDEX idx_tenants_subscription ON tenants(subscription_status, subscription_expires_at); CREATE INDEX idx_tenants_trial ON tenants(trial_ends_at) WHERE trial_ends_at IS NOT NULL; -- Full-text search for marketplace directory CREATE INDEX idx_tenants_search ON tenants USING GIN(to_tsvector('english', name || ' ' || COALESCE(city, '') || ' ' || COALESCE(country, '') )); COMMENT ON TABLE tenants IS 'Organizations in marketplace - discoverable without RLS (matches Go models.Tenant)'; COMMENT ON COLUMN tenants.slug IS 'URL-friendly unique identifier generated from name'; COMMENT ON COLUMN tenants.status IS 'active, inactive, suspended, deleted (NOT boolean is_active)'; -- ============================================================================= -- SECTION 4: USERS TABLE -- ============================================================================= -- User accounts with complete profile support -- ✅ Matches Go model exactly (first_name, last_name, full_name, etc.) -- ✅ NO strict RLS - profiles discoverable in marketplace -- ============================================================================= CREATE TABLE users ( -- Identity 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 (matches Go model - first_name, last_name, full_name) first_name VARCHAR(255), last_name VARCHAR(255), full_name VARCHAR(255), -- Will be auto-generated via trigger avatar_url TEXT, phone VARCHAR(50), -- Role & permissions (matches Go model) role user_role NOT NULL DEFAULT 'consumer', -- Account status (matches Go model - status string, NOT is_active boolean) status VARCHAR(50) NOT NULL DEFAULT 'active', email_verified BOOLEAN NOT NULL DEFAULT false, email_verified_at TIMESTAMPTZ, is_onboarded BOOLEAN NOT NULL DEFAULT false, -- Activity tracking (matches Go model - includes last_login_ip) last_login_at TIMESTAMPTZ, last_login_ip INET, -- Audit fields 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,}$'), CONSTRAINT chk_user_status CHECK ( status IN ('active', 'inactive', 'suspended', 'pending_verification') ) ); -- Performance 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_status ON users(status) WHERE status = 'active'; CREATE INDEX idx_users_tenant_role ON users(tenant_id, role); -- Full-text search for user discovery in marketplace CREATE INDEX idx_users_search ON users USING GIN(to_tsvector('english', COALESCE(full_name, '') || ' ' || COALESCE(first_name, '') || ' ' || COALESCE(last_name, '') || ' ' || email )); COMMENT ON TABLE users IS 'User accounts - profiles discoverable in marketplace (matches Go models.User)'; COMMENT ON COLUMN users.full_name IS 'Auto-generated from first_name + last_name via trigger'; COMMENT ON COLUMN users.status IS 'String status (active, inactive, suspended, pending_verification) NOT boolean'; COMMENT ON COLUMN users.email_verified IS 'Boolean flag (separate from email_verified_at timestamp)'; -- ============================================================================= -- SECTION 5: CONTRACTS TABLE -- ============================================================================= -- Agreements between vendors and consumers -- ✅ RLS allows BOTH vendor and consumer tenants to access (collaboration-aware) -- ============================================================================= CREATE TABLE contracts ( -- Identity id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, -- Parties (vendor provides service, consumer receives it) vendor_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, consumer_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, -- Contract details title VARCHAR(500) NOT NULL, description TEXT, status contract_status NOT NULL DEFAULT 'draft', -- Timeline start_date DATE NOT NULL, end_date DATE NOT NULL, -- Financial terms total_amount NUMERIC(12,2) NOT NULL DEFAULT 0.00, currency VARCHAR(3) NOT NULL DEFAULT 'USD', -- Concurrency control version INTEGER NOT NULL DEFAULT 1, -- Audit fields 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) ); -- Performance 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); -- Full-text search CREATE INDEX idx_contracts_search ON contracts USING GIN(to_tsvector('english', title || ' ' || COALESCE(description, ''))); COMMENT ON TABLE contracts IS 'Vendor-consumer agreements with collaboration-aware RLS (both parties can access)'; COMMENT ON COLUMN contracts.tenant_id IS 'Primary tenant (usually vendor) but both vendor/consumer tenants have access'; -- ============================================================================= -- SECTION 6: DELIVERABLES TABLE -- ============================================================================= CREATE TABLE deliverables ( -- Identity 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, -- Deliverable details title VARCHAR(500) NOT NULL, description TEXT, sequence_number INTEGER NOT NULL, status deliverable_status NOT NULL DEFAULT 'pending', -- Timeline deadline DATE NOT NULL, submitted_at TIMESTAMPTZ, approved_at TIMESTAMPTZ, -- Workflow tracking submitted_by UUID REFERENCES users(id) ON DELETE SET NULL, approved_by UUID REFERENCES users(id) ON DELETE SET NULL, -- Audit fields 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); COMMENT ON TABLE deliverables IS 'Work items within contracts - inherit collaboration from parent contract'; -- ============================================================================= -- SECTION 7: MILESTONES TABLE -- ============================================================================= CREATE TABLE milestones ( -- Identity 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, -- Milestone configuration 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', -- Completion tracking completed_at TIMESTAMPTZ, -- Audit fields created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, -- Constraints CONSTRAINT valid_milestone_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); COMMENT ON TABLE milestones IS 'Payment milestones with flexible scheduling logic'; -- ============================================================================= -- SECTION 8: SUPPORTING TABLES -- ============================================================================= -- ----------------------------------------------------------------------------- -- Comments Table (Polymorphic - can comment on any entity) -- ----------------------------------------------------------------------------- CREATE TABLE comments ( -- Identity id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, -- Polymorphic relationship entity_type VARCHAR(50) NOT NULL, entity_id UUID NOT NULL, -- Comment content content TEXT NOT NULL, -- Author user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, -- Audit fields created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, -- Constraints CONSTRAINT valid_comment_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); COMMENT ON TABLE comments IS 'Discussion comments on contracts, deliverables, milestones'; -- ----------------------------------------------------------------------------- -- Attachments Table (File storage metadata) -- ----------------------------------------------------------------------------- CREATE TABLE attachments ( -- Identity id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, -- Polymorphic relationship 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, -- S3/MinIO object key -- Status tracking status VARCHAR(20) NOT NULL DEFAULT 'pending', -- Upload tracking uploaded_by UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, uploaded_at TIMESTAMPTZ, -- Audit fields created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, -- Constraints CONSTRAINT valid_attachment_size CHECK (size > 0), CONSTRAINT valid_attachment_status CHECK ( status IN ('pending', 'uploaded', 'processing', 'failed') ), CONSTRAINT valid_attachment_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); COMMENT ON TABLE attachments IS 'File attachments stored in MinIO/S3'; -- ----------------------------------------------------------------------------- -- Audit Logs Table -- ----------------------------------------------------------------------------- CREATE TABLE audit_logs ( -- Identity 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 information actor_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, -- Change tracking old_values JSONB, new_values JSONB, -- Security 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); COMMENT ON TABLE audit_logs IS 'Immutable audit trail for compliance'; -- ----------------------------------------------------------------------------- -- Analytics Events Table -- ----------------------------------------------------------------------------- CREATE TABLE analytics_events ( -- Identity 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); COMMENT ON TABLE analytics_events IS 'User behavior and system events for analytics'; -- ----------------------------------------------------------------------------- -- Notifications Table -- ----------------------------------------------------------------------------- CREATE TABLE notifications ( -- Identity 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, -- Notification content type VARCHAR(50) NOT NULL, title VARCHAR(255) NOT NULL, message TEXT NOT NULL, -- Related entity (optional) entity_type VARCHAR(50), entity_id UUID, -- Read status read_at TIMESTAMPTZ, -- Timestamp 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); COMMENT ON TABLE notifications IS 'In-app notifications with read/unread tracking'; -- ============================================================================= -- SECTION 9: TRIGGERS FOR AUTOMATIC UPDATES -- ============================================================================= -- ----------------------------------------------------------------------------- -- Trigger: Auto-update updated_at column -- ----------------------------------------------------------------------------- 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(); -- ----------------------------------------------------------------------------- -- Trigger: Auto-generate full_name from first_name + last_name -- ----------------------------------------------------------------------------- CREATE OR REPLACE FUNCTION generate_full_name() RETURNS TRIGGER AS $$ BEGIN NEW.full_name := TRIM( COALESCE(NEW.first_name, '') || ' ' || COALESCE(NEW.last_name, '') ); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER update_user_full_name BEFORE INSERT OR UPDATE OF first_name, last_name ON users FOR EACH ROW EXECUTE FUNCTION generate_full_name(); COMMENT ON FUNCTION generate_full_name() IS 'Auto-generates full_name from first_name + last_name'; -- ============================================================================= -- SECTION 10: ROW-LEVEL SECURITY (MARKETPLACE-AWARE) -- ============================================================================= -- Enable RLS on all 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; -- ----------------------------------------------------------------------------- -- Tenants: Marketplace discovery (allow NULL tenant_id for registration) -- ----------------------------------------------------------------------------- CREATE POLICY tenants_marketplace_access ON tenants FOR ALL USING ( -- Own tenant id = current_setting('app.current_tenant_id', true)::UUID OR -- Allow during registration (no tenant context yet) current_setting('app.current_tenant_id', true) IS NULL OR -- Public tenants (for marketplace directory - all tenants visible) status = 'active' ) WITH CHECK ( id = current_setting('app.current_tenant_id', true)::UUID OR current_setting('app.current_tenant_id', true) IS NULL ); COMMENT ON POLICY tenants_marketplace_access ON tenants IS 'Allows marketplace discovery of active tenants + registration without tenant context'; -- ----------------------------------------------------------------------------- -- Users: Marketplace discovery (vendor/consumer profiles visible) -- ----------------------------------------------------------------------------- CREATE POLICY users_marketplace_access ON users FOR ALL USING ( -- Own tenant users tenant_id = current_setting('app.current_tenant_id', true)::UUID OR -- Allow during registration (no tenant context yet) current_setting('app.current_tenant_id', true) IS NULL OR -- Active users from other tenants (marketplace discovery) status = 'active' ) WITH CHECK ( tenant_id = current_setting('app.current_tenant_id', true)::UUID OR current_setting('app.current_tenant_id', true) IS NULL ); COMMENT ON POLICY users_marketplace_access ON users IS 'Allows discovery of active users across tenants + registration flow'; -- ----------------------------------------------------------------------------- -- Contracts: Collaboration-aware (both vendor and consumer can access) -- ----------------------------------------------------------------------------- CREATE POLICY contracts_collaboration_access ON contracts FOR ALL USING ( -- Vendor's tenant EXISTS ( SELECT 1 FROM users WHERE users.id = contracts.vendor_id AND users.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR -- Consumer's tenant EXISTS ( SELECT 1 FROM users WHERE users.id = contracts.consumer_id AND users.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR -- Allow during creation current_setting('app.current_tenant_id', true) IS NULL ) WITH CHECK ( EXISTS ( SELECT 1 FROM users WHERE users.id = contracts.vendor_id AND users.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR EXISTS ( SELECT 1 FROM users WHERE users.id = contracts.consumer_id AND users.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR current_setting('app.current_tenant_id', true) IS NULL ); COMMENT ON POLICY contracts_collaboration_access ON contracts IS 'Allows both vendor and consumer tenants to access contract (marketplace collaboration)'; -- ----------------------------------------------------------------------------- -- Deliverables: Inherit collaboration from parent contract -- ----------------------------------------------------------------------------- CREATE POLICY deliverables_collaboration_access ON deliverables FOR ALL USING ( EXISTS ( SELECT 1 FROM contracts c WHERE c.id = deliverables.contract_id AND ( EXISTS ( SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR EXISTS ( SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) ) ) OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Milestones: Inherit collaboration via deliverable → contract -- ----------------------------------------------------------------------------- CREATE POLICY milestones_collaboration_access ON milestones FOR ALL USING ( EXISTS ( SELECT 1 FROM deliverables d JOIN contracts c ON c.id = d.contract_id WHERE d.id = milestones.deliverable_id AND ( EXISTS ( SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) OR EXISTS ( SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID ) ) ) OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Comments: Inherit collaboration from parent entity -- ----------------------------------------------------------------------------- CREATE POLICY comments_collaboration_access ON comments FOR ALL USING ( -- Comments on contracts (entity_type = 'contract' AND EXISTS ( SELECT 1 FROM contracts c WHERE c.id = comments.entity_id AND ( EXISTS (SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) OR EXISTS (SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) ) ) ) OR -- Comments on deliverables (entity_type = 'deliverable' AND EXISTS ( SELECT 1 FROM deliverables d JOIN contracts c ON c.id = d.contract_id WHERE d.id = comments.entity_id AND ( EXISTS (SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) OR EXISTS (SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) ) ) ) OR -- Comments on milestones (entity_type = 'milestone' AND EXISTS ( SELECT 1 FROM milestones m JOIN deliverables d ON d.id = m.deliverable_id JOIN contracts c ON c.id = d.contract_id WHERE m.id = comments.entity_id AND ( EXISTS (SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) OR EXISTS (SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) ) ) ) OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Attachments: Similar to comments -- ----------------------------------------------------------------------------- CREATE POLICY attachments_collaboration_access ON attachments FOR ALL USING ( (entity_type = 'contract' AND EXISTS ( SELECT 1 FROM contracts c WHERE c.id = attachments.entity_id AND ( EXISTS (SELECT 1 FROM users u WHERE u.id = c.vendor_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) OR EXISTS (SELECT 1 FROM users u WHERE u.id = c.consumer_id AND u.tenant_id = current_setting('app.current_tenant_id', true)::UUID) ) ) ) OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Audit Logs: Strict tenant isolation -- ----------------------------------------------------------------------------- CREATE POLICY audit_logs_tenant_isolation ON audit_logs USING ( tenant_id = current_setting('app.current_tenant_id', true)::UUID OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Analytics: System-wide OR tenant-specific -- ----------------------------------------------------------------------------- CREATE POLICY analytics_events_access ON analytics_events USING ( tenant_id = current_setting('app.current_tenant_id', true)::UUID OR tenant_id IS NULL OR current_setting('app.current_tenant_id', true) IS NULL ); -- ----------------------------------------------------------------------------- -- Notifications: Strict tenant isolation -- ----------------------------------------------------------------------------- CREATE POLICY notifications_tenant_isolation ON notifications USING ( tenant_id = current_setting('app.current_tenant_id', true)::UUID OR current_setting('app.current_tenant_id', true) IS NULL ); -- ============================================================================= -- END OF MIGRATION 000001_initial_schema.up.sql -- =============================================================================