-- ============================================================================= -- 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 -- =============================================================================