GT AI OS Community v2.0.33 - Add NVIDIA NIM and Nemotron agents

- Updated python_coding_microproject.csv to use NVIDIA NIM Kimi K2
- Updated kali_linux_shell_simulator.csv to use NVIDIA NIM Kimi K2
  - Made more general-purpose (flexible targets, expanded tools)
- Added nemotron-mini-agent.csv for fast local inference via Ollama
- Added nemotron-agent.csv for advanced reasoning via Ollama
- Added wiki page: Projects for NVIDIA NIMs and Nemotron
This commit is contained in:
HackWeasel
2025-12-12 17:47:14 -05:00
commit 310491a557
750 changed files with 232701 additions and 0 deletions

View File

@@ -0,0 +1,106 @@
-- Migration T001: Rename 'teams' table to 'tenants' for semantic clarity
-- Date: November 6, 2025
--
-- RATIONALE:
-- The 'teams' table is misnamed - it stores TENANT metadata (one row per tenant),
-- not user collaboration teams. This rename eliminates confusion and frees up the
-- 'teams' name for actual user collaboration features.
--
-- IMPACT:
-- - Renames table: teams → tenants
-- - Renames all foreign key columns: team_id → tenant_id
-- - Updates all constraints and indexes
-- - NO DATA LOSS - purely structural rename
--
-- IDEMPOTENT: Can be run multiple times safely
-- ROLLBACK: See rollback script: T001_rollback.sql
-- Note: When run via docker exec, we're already connected to gt2_tenants
-- So we don't use \c command here
SET search_path TO tenant_test_company, public;
BEGIN;
-- Idempotency wrapper: Only run if migration hasn't been applied yet
DO $$
DECLARE
teams_exists BOOLEAN;
tenants_exists BOOLEAN;
BEGIN
-- Check if old 'teams' table exists and new 'tenants' table doesn't
SELECT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'teams'
) INTO teams_exists;
SELECT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'tenants'
) INTO tenants_exists;
IF teams_exists AND NOT tenants_exists THEN
RAISE NOTICE 'Migration T001: Applying teams → tenants rename...';
-- Step 1: Rename the table
ALTER TABLE teams RENAME TO tenants;
-- Step 2: Rename foreign key columns in all dependent tables
ALTER TABLE users RENAME COLUMN team_id TO tenant_id;
ALTER TABLE agents RENAME COLUMN team_id TO tenant_id;
ALTER TABLE datasets RENAME COLUMN team_id TO tenant_id;
ALTER TABLE conversations RENAME COLUMN team_id TO tenant_id;
ALTER TABLE documents RENAME COLUMN team_id TO tenant_id;
ALTER TABLE document_chunks RENAME COLUMN team_id TO tenant_id;
-- Step 3: Rename foreign key constraints
ALTER TABLE users RENAME CONSTRAINT users_team_id_fkey TO users_tenant_id_fkey;
ALTER TABLE agents RENAME CONSTRAINT agents_team_id_fkey TO agents_tenant_id_fkey;
ALTER TABLE datasets RENAME CONSTRAINT datasets_team_id_fkey TO datasets_tenant_id_fkey;
ALTER TABLE conversations RENAME CONSTRAINT conversations_team_id_fkey TO conversations_tenant_id_fkey;
ALTER TABLE documents RENAME CONSTRAINT documents_team_id_fkey TO documents_tenant_id_fkey;
ALTER TABLE document_chunks RENAME CONSTRAINT document_chunks_team_id_fkey TO document_chunks_tenant_id_fkey;
-- Step 4: Rename indexes
ALTER INDEX IF EXISTS idx_teams_domain RENAME TO idx_tenants_domain;
ALTER INDEX IF EXISTS idx_users_team_id RENAME TO idx_users_tenant_id;
ALTER INDEX IF EXISTS idx_agents_team_id RENAME TO idx_agents_tenant_id;
ALTER INDEX IF EXISTS idx_datasets_team_id RENAME TO idx_datasets_tenant_id;
ALTER INDEX IF EXISTS idx_conversations_team_id RENAME TO idx_conversations_tenant_id;
ALTER INDEX IF EXISTS idx_documents_team_id RENAME TO idx_documents_tenant_id;
ALTER INDEX IF EXISTS idx_document_chunks_team_id RENAME TO idx_document_chunks_tenant_id;
RAISE NOTICE '✅ Migration T001 applied successfully!';
RAISE NOTICE ' - Table renamed: teams → tenants';
RAISE NOTICE ' - Columns renamed: team_id → tenant_id (6 tables)';
RAISE NOTICE ' - Constraints renamed: 6 foreign keys';
RAISE NOTICE ' - Indexes renamed: 7 indexes';
ELSIF NOT teams_exists AND tenants_exists THEN
RAISE NOTICE '✅ Migration T001 already applied (tenants table exists, teams table renamed)';
ELSIF teams_exists AND tenants_exists THEN
RAISE WARNING '⚠️ Migration T001 in inconsistent state: both teams and tenants tables exist!';
RAISE WARNING ' Manual intervention may be required.';
ELSE
RAISE WARNING '⚠️ Migration T001 cannot run: neither teams nor tenants table exists!';
RAISE WARNING ' Check if schema is properly initialized.';
END IF;
END $$;
COMMIT;
-- Verification query
DO $$
DECLARE
tenant_count INTEGER;
user_count INTEGER;
BEGIN
SELECT COUNT(*) INTO tenant_count FROM tenants;
SELECT COUNT(*) INTO user_count FROM users;
RAISE NOTICE 'Migration T001 verification:';
RAISE NOTICE ' Tenants: % rows', tenant_count;
RAISE NOTICE ' Users: % rows', user_count;
END $$;

View File

@@ -0,0 +1,91 @@
-- Rollback Migration T001: Rename 'tenants' table back to 'teams'
-- Date: November 6, 2025
--
-- This script reverses the T001_rename_teams_to_tenants.sql migration
-- Use only if you need to rollback the migration for any reason
--
-- NO DATA LOSS - purely structural rename back to original state
-- IDEMPOTENT: Can be run multiple times safely
SET search_path TO tenant_test_company, public;
BEGIN;
-- Idempotency wrapper: Only run if rollback hasn't been applied yet
DO $$
DECLARE
teams_exists BOOLEAN;
tenants_exists BOOLEAN;
BEGIN
-- Check current state
SELECT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'teams'
) INTO teams_exists;
SELECT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'tenants'
) INTO tenants_exists;
IF NOT teams_exists AND tenants_exists THEN
RAISE NOTICE 'Rollback T001: Reverting tenants → teams rename...';
-- Step 1: Rename the table back
ALTER TABLE tenants RENAME TO teams;
-- Step 2: Rename foreign key columns back
ALTER TABLE users RENAME COLUMN tenant_id TO team_id;
ALTER TABLE agents RENAME COLUMN tenant_id TO team_id;
ALTER TABLE datasets RENAME COLUMN tenant_id TO team_id;
ALTER TABLE conversations RENAME COLUMN tenant_id TO team_id;
ALTER TABLE documents RENAME COLUMN tenant_id TO team_id;
ALTER TABLE document_chunks RENAME COLUMN tenant_id TO team_id;
-- Step 3: Rename foreign key constraints back
ALTER TABLE users RENAME CONSTRAINT users_tenant_id_fkey TO users_team_id_fkey;
ALTER TABLE agents RENAME CONSTRAINT agents_tenant_id_fkey TO agents_team_id_fkey;
ALTER TABLE datasets RENAME CONSTRAINT datasets_tenant_id_fkey TO datasets_team_id_fkey;
ALTER TABLE conversations RENAME CONSTRAINT conversations_tenant_id_fkey TO conversations_team_id_fkey;
ALTER TABLE documents RENAME CONSTRAINT documents_tenant_id_fkey TO documents_team_id_fkey;
ALTER TABLE document_chunks RENAME CONSTRAINT document_chunks_tenant_id_fkey TO document_chunks_team_id_fkey;
-- Step 4: Rename indexes back
ALTER INDEX IF EXISTS idx_tenants_domain RENAME TO idx_teams_domain;
ALTER INDEX IF EXISTS idx_users_tenant_id RENAME TO idx_users_team_id;
ALTER INDEX IF EXISTS idx_agents_tenant_id RENAME TO idx_agents_team_id;
ALTER INDEX IF EXISTS idx_datasets_tenant_id RENAME TO idx_datasets_team_id;
ALTER INDEX IF EXISTS idx_conversations_tenant_id RENAME TO idx_conversations_team_id;
ALTER INDEX IF EXISTS idx_documents_tenant_id RENAME TO idx_documents_team_id;
ALTER INDEX IF EXISTS idx_document_chunks_tenant_id RENAME TO idx_document_chunks_team_id;
RAISE NOTICE '✅ Rollback T001 completed successfully!';
RAISE NOTICE ' - Table renamed: tenants → teams';
RAISE NOTICE ' - Columns renamed: tenant_id → team_id (6 tables)';
RAISE NOTICE ' - Constraints renamed: 6 foreign keys';
RAISE NOTICE ' - Indexes renamed: 7 indexes';
ELSIF teams_exists AND NOT tenants_exists THEN
RAISE NOTICE '✅ Rollback T001 already applied (teams table exists, tenants table not found)';
ELSE
RAISE WARNING '⚠️ Rollback T001 cannot determine state: teams=%,tenants=%', teams_exists, tenants_exists;
END IF;
END $$;
COMMIT;
-- Verification
DO $$
DECLARE
team_count INTEGER;
user_count INTEGER;
BEGIN
SELECT COUNT(*) INTO team_count FROM teams;
SELECT COUNT(*) INTO user_count FROM users;
RAISE NOTICE 'Rollback T001 verification:';
RAISE NOTICE ' Teams: % rows', team_count;
RAISE NOTICE ' Users: % rows', user_count;
END $$;

View File

@@ -0,0 +1,34 @@
-- Migration: Add invitation status tracking to team_memberships
-- Created: 2025-01-07
-- Purpose: Enable team invitation accept/decline workflow
SET search_path TO tenant_test_company, public;
-- Add status tracking columns
ALTER TABLE team_memberships
ADD COLUMN IF NOT EXISTS status VARCHAR(20) DEFAULT 'accepted'
CHECK (status IN ('pending', 'accepted', 'declined'));
ALTER TABLE team_memberships
ADD COLUMN IF NOT EXISTS invited_at TIMESTAMPTZ DEFAULT NOW();
ALTER TABLE team_memberships
ADD COLUMN IF NOT EXISTS responded_at TIMESTAMPTZ;
-- Update existing memberships to 'accepted' status
-- This ensures backward compatibility with existing data
UPDATE team_memberships
SET status = 'accepted', invited_at = created_at
WHERE status IS NULL;
-- Create index for efficient pending invitation queries
CREATE INDEX IF NOT EXISTS idx_team_memberships_status
ON team_memberships(user_id, status);
CREATE INDEX IF NOT EXISTS idx_team_memberships_team_status
ON team_memberships(team_id, status);
-- Add comment for documentation
COMMENT ON COLUMN team_memberships.status IS 'Invitation status: pending (invited), accepted (active member), declined (rejected invitation)';
COMMENT ON COLUMN team_memberships.invited_at IS 'Timestamp when invitation was sent';
COMMENT ON COLUMN team_memberships.responded_at IS 'Timestamp when invitation was accepted or declined';

View File

@@ -0,0 +1,216 @@
-- Migration T002: Create User Collaboration Teams Tables
-- Date: November 6, 2025
--
-- PURPOSE:
-- Creates tables for user collaboration teams (different from tenant metadata).
-- Users can create teams, invite members, and share agents/datasets with team members.
--
-- TABLES CREATED:
-- 1. teams - User collaboration teams (NOT tenant metadata)
-- 2. team_memberships - Team members with two-tier permissions
--
-- PERMISSION MODEL:
-- Tier 1 (Team-level): 'read' (access resources) or 'share' (access + share own resources)
-- Tier 2 (Resource-level): Per-user permissions stored in JSONB {"agent:uuid": "read|edit"}
--
-- IDEMPOTENT: Can be run multiple times safely
-- DEPENDS ON: T001_rename_teams_to_tenants.sql (must run first)
-- Note: When run via docker exec, we're already connected to gt2_tenants
SET search_path TO tenant_test_company, public;
BEGIN;
-- Table 1: User Collaboration Teams
-- This is the NEW teams table for user collaboration (replaces old misnamed tenant table)
DO $$
BEGIN
IF NOT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'teams'
) THEN
CREATE TABLE teams (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL,
description TEXT,
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, -- Tenant isolation
owner_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, -- Team owner
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
RAISE NOTICE '✅ Created teams table for user collaboration';
ELSE
RAISE NOTICE '✅ Teams table already exists';
END IF;
END $$;
-- Table 2: Team Memberships with Two-Tier Permissions
DO $$
BEGIN
IF NOT EXISTS (
SELECT FROM information_schema.tables
WHERE table_schema = 'tenant_test_company'
AND table_name = 'team_memberships'
) THEN
CREATE TABLE team_memberships (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
-- Tier 1: Team-level permission (set by team owner)
team_permission VARCHAR(20) NOT NULL DEFAULT 'read'
CHECK (team_permission IN ('read', 'share')),
-- 'read' = can access resources shared to this team
-- 'share' = can access resources AND share own resources to this team
-- Tier 2: Resource-level permissions (set by resource sharer when sharing)
-- JSONB structure: {"agent:uuid": "read|edit", "dataset:uuid": "read|edit"}
resource_permissions JSONB DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(team_id, user_id) -- Prevent duplicate memberships
);
RAISE NOTICE '✅ Created team_memberships table';
ELSE
RAISE NOTICE '✅ Team_memberships table already exists';
END IF;
END $$;
-- Performance indexes
DO $$
BEGIN
IF NOT EXISTS (
SELECT FROM pg_indexes
WHERE schemaname = 'tenant_test_company'
AND indexname = 'idx_teams_owner_id'
) THEN
CREATE INDEX idx_teams_owner_id ON teams(owner_id);
RAISE NOTICE '✅ Created index: idx_teams_owner_id';
END IF;
IF NOT EXISTS (
SELECT FROM pg_indexes
WHERE schemaname = 'tenant_test_company'
AND indexname = 'idx_teams_tenant_id'
) THEN
CREATE INDEX idx_teams_tenant_id ON teams(tenant_id);
RAISE NOTICE '✅ Created index: idx_teams_tenant_id';
END IF;
IF NOT EXISTS (
SELECT FROM pg_indexes
WHERE schemaname = 'tenant_test_company'
AND indexname = 'idx_team_memberships_team_id'
) THEN
CREATE INDEX idx_team_memberships_team_id ON team_memberships(team_id);
RAISE NOTICE '✅ Created index: idx_team_memberships_team_id';
END IF;
IF NOT EXISTS (
SELECT FROM pg_indexes
WHERE schemaname = 'tenant_test_company'
AND indexname = 'idx_team_memberships_user_id'
) THEN
CREATE INDEX idx_team_memberships_user_id ON team_memberships(user_id);
RAISE NOTICE '✅ Created index: idx_team_memberships_user_id';
END IF;
IF NOT EXISTS (
SELECT FROM pg_indexes
WHERE schemaname = 'tenant_test_company'
AND indexname = 'idx_team_memberships_resources'
) THEN
CREATE INDEX idx_team_memberships_resources ON team_memberships USING gin(resource_permissions);
RAISE NOTICE '✅ Created index: idx_team_memberships_resources';
END IF;
END $$;
-- Function: Auto-unshare resources when user loses 'share' permission
DO $$
BEGIN
IF NOT EXISTS (
SELECT FROM pg_proc p
JOIN pg_namespace n ON p.pronamespace = n.oid
WHERE n.nspname = 'tenant_test_company'
AND p.proname = 'auto_unshare_on_permission_downgrade'
) THEN
CREATE FUNCTION auto_unshare_on_permission_downgrade()
RETURNS TRIGGER AS $func$
BEGIN
-- If team_permission changed from 'share' to 'read'
IF OLD.team_permission = 'share' AND NEW.team_permission = 'read' THEN
-- Clear all resource permissions for this user
-- (they can no longer share resources, so remove what they shared)
NEW.resource_permissions := '{}'::jsonb;
RAISE NOTICE 'Auto-unshared all resources for user % in team % due to permission downgrade',
NEW.user_id, NEW.team_id;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
RAISE NOTICE '✅ Created function: auto_unshare_on_permission_downgrade';
ELSE
RAISE NOTICE '✅ Function auto_unshare_on_permission_downgrade already exists';
END IF;
END $$;
-- Trigger: Apply auto-unshare logic
DO $$
BEGIN
IF NOT EXISTS (
SELECT FROM pg_trigger
WHERE tgname = 'trigger_auto_unshare'
) THEN
CREATE TRIGGER trigger_auto_unshare
BEFORE UPDATE OF team_permission ON team_memberships
FOR EACH ROW
EXECUTE FUNCTION auto_unshare_on_permission_downgrade();
RAISE NOTICE '✅ Created trigger: trigger_auto_unshare';
ELSE
RAISE NOTICE '✅ Trigger trigger_auto_unshare already exists';
END IF;
END $$;
-- Grant permissions
DO $$
BEGIN
GRANT SELECT, INSERT, UPDATE, DELETE ON teams TO gt2_tenant_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON team_memberships TO gt2_tenant_user;
RAISE NOTICE '✅ Granted permissions to gt2_tenant_user';
EXCEPTION
WHEN undefined_object THEN
RAISE NOTICE '⚠️ Role gt2_tenant_user does not exist (ok for fresh installs)';
END $$;
COMMIT;
-- Final verification
DO $$
DECLARE
teams_count INTEGER;
memberships_count INTEGER;
BEGIN
SELECT COUNT(*) INTO teams_count FROM teams;
SELECT COUNT(*) INTO memberships_count FROM team_memberships;
RAISE NOTICE '';
RAISE NOTICE '========================================';
RAISE NOTICE '✅ Migration T002 completed successfully!';
RAISE NOTICE '========================================';
RAISE NOTICE 'Tables created:';
RAISE NOTICE ' - teams (user collaboration): % rows', teams_count;
RAISE NOTICE ' - team_memberships: % rows', memberships_count;
RAISE NOTICE 'Indexes: 5 created';
RAISE NOTICE 'Functions: 1 created';
RAISE NOTICE 'Triggers: 1 created';
RAISE NOTICE '========================================';
END $$;

View File

@@ -0,0 +1,313 @@
-- Migration T003: Team Resource Sharing System
-- Purpose: Enable multi-team resource sharing for agents and datasets
-- Dependencies: T002_create_collaboration_teams.sql
-- Author: GT 2.0 Development Team
-- Date: 2025-01-07
-- Set schema for tenant isolation
SET search_path TO tenant_test_company;
-- ============================================================================
-- SECTION 1: Junction Table for Many-to-Many Resource Sharing
-- ============================================================================
CREATE TABLE IF NOT EXISTS team_resource_shares (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE,
resource_type VARCHAR(20) NOT NULL CHECK (resource_type IN ('agent', 'dataset')),
resource_id UUID NOT NULL,
shared_by UUID NOT NULL REFERENCES users(id),
created_at TIMESTAMP DEFAULT NOW(),
-- Ensure each resource can only be shared once per team
UNIQUE(team_id, resource_type, resource_id)
);
COMMENT ON TABLE team_resource_shares IS 'Junction table for sharing agents/datasets with collaboration teams';
COMMENT ON COLUMN team_resource_shares.resource_type IS 'Type of resource: agent or dataset';
COMMENT ON COLUMN team_resource_shares.resource_id IS 'UUID of the agent or dataset being shared';
COMMENT ON COLUMN team_resource_shares.shared_by IS 'User who shared this resource with the team';
-- ============================================================================
-- SECTION 2: Performance Indexes
-- ============================================================================
-- Index for finding all teams a resource is shared with
CREATE INDEX idx_trs_resource ON team_resource_shares(resource_type, resource_id);
-- Index for finding all resources shared with a team
CREATE INDEX idx_trs_team ON team_resource_shares(team_id);
-- Index for finding resources shared by a specific user
CREATE INDEX idx_trs_shared_by ON team_resource_shares(shared_by);
-- Composite index for common access checks
CREATE INDEX idx_trs_lookup ON team_resource_shares(team_id, resource_type, resource_id);
-- ============================================================================
-- SECTION 3: Helper View #1 - Individual User Resource Access
-- ============================================================================
-- Purpose: Flatten team memberships + resource shares for fast permission checks
-- Usage: Check if specific user has access to specific resource
CREATE VIEW user_resource_access AS
SELECT
tm.user_id,
trs.resource_type,
trs.resource_id,
tm.resource_permissions->(trs.resource_type || ':' || trs.resource_id::text) as permission,
tm.team_id,
tm.team_permission,
trs.shared_by,
trs.created_at
FROM team_memberships tm
JOIN team_resource_shares trs ON tm.team_id = trs.team_id
WHERE tm.resource_permissions ? (trs.resource_type || ':' || trs.resource_id::text);
COMMENT ON VIEW user_resource_access IS 'Flattened view of user access to resources via team memberships';
-- Note: Indexes on views are not supported in standard PostgreSQL
-- For performance, consider creating a materialized view if needed
-- ============================================================================
-- SECTION 4: Helper View #2 - Aggregated User Accessible Resources
-- ============================================================================
-- Purpose: Aggregate resources by user for efficient listing
-- Usage: Get all agents/datasets accessible to a user (for list views)
CREATE VIEW user_accessible_resources AS
SELECT
tm.user_id,
trs.resource_type,
trs.resource_id,
MAX(CASE
WHEN tm.resource_permissions->(trs.resource_type || ':' || trs.resource_id::text) = '"edit"'::jsonb
THEN 'edit'
WHEN tm.resource_permissions->(trs.resource_type || ':' || trs.resource_id::text) = '"read"'::jsonb
THEN 'read'
ELSE 'none'
END) as best_permission,
COUNT(DISTINCT tm.team_id) as shared_in_teams,
ARRAY_AGG(DISTINCT tm.team_id) as team_ids,
MIN(trs.created_at) as first_shared_at
FROM team_memberships tm
JOIN team_resource_shares trs ON tm.team_id = trs.team_id
WHERE tm.resource_permissions ? (trs.resource_type || ':' || trs.resource_id::text)
GROUP BY tm.user_id, trs.resource_type, trs.resource_id;
COMMENT ON VIEW user_accessible_resources IS 'Aggregated view showing all resources accessible to each user with best permission level';
-- Note: Indexes on views are not supported in standard PostgreSQL
-- For performance, consider creating a materialized view if needed
-- ============================================================================
-- SECTION 5: Cascade Cleanup Trigger
-- ============================================================================
-- Purpose: When a resource is unshared from a team, clean up member permissions
-- Note: The ON DELETE CASCADE on team_resource_shares already handles team deletion
CREATE OR REPLACE FUNCTION cleanup_resource_permissions()
RETURNS TRIGGER AS $$
BEGIN
-- Remove the resource permission key from all team members
UPDATE team_memberships
SET resource_permissions = resource_permissions - (OLD.resource_type || ':' || OLD.resource_id::text)
WHERE team_id = OLD.team_id
AND resource_permissions ? (OLD.resource_type || ':' || OLD.resource_id::text);
RETURN OLD;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_cleanup_resource_permissions
BEFORE DELETE ON team_resource_shares
FOR EACH ROW
EXECUTE FUNCTION cleanup_resource_permissions();
COMMENT ON FUNCTION cleanup_resource_permissions IS 'Removes resource permission entries from team members when resource is unshared';
-- ============================================================================
-- SECTION 6: Validation Function
-- ============================================================================
-- Purpose: Validate that a user has 'share' permission before sharing resources
CREATE OR REPLACE FUNCTION validate_resource_share()
RETURNS TRIGGER AS $$
DECLARE
user_team_permission VARCHAR(20);
BEGIN
-- Check if the user has 'share' permission on the team
SELECT team_permission INTO user_team_permission
FROM team_memberships
WHERE team_id = NEW.team_id
AND user_id = NEW.shared_by;
IF user_team_permission IS NULL THEN
RAISE EXCEPTION 'User % is not a member of team %', NEW.shared_by, NEW.team_id;
END IF;
IF user_team_permission != 'share' THEN
RAISE EXCEPTION 'User % does not have share permission on team %', NEW.shared_by, NEW.team_id;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_validate_resource_share
BEFORE INSERT ON team_resource_shares
FOR EACH ROW
EXECUTE FUNCTION validate_resource_share();
COMMENT ON FUNCTION validate_resource_share IS 'Ensures only users with share permission can share resources to teams';
-- ============================================================================
-- SECTION 6B: Sync JSONB Permissions When Resource Shared
-- ============================================================================
-- Purpose: Automatically update team_memberships.resource_permissions when
-- a resource is shared to a team. This ensures database-level consistency.
CREATE OR REPLACE FUNCTION sync_resource_permissions_on_share()
RETURNS TRIGGER AS $$
BEGIN
-- Note: This trigger is called AFTER validation, so we know the share is valid
-- The actual permission levels (read/edit) are set by the application layer
-- This trigger just ensures the resource key exists in the JSONB
--
-- The application will call a separate function to set individual user permissions
-- after this trigger runs. This is a two-step process:
-- 1. This trigger: Ensure resource is known to the team
-- 2. Application: Set per-user permissions via update_member_resource_permission()
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Note: We're keeping this trigger simple for now. The application layer handles
-- per-user permission assignment. A future optimization could move all permission
-- logic into triggers, but that requires storing default permissions in team_resource_shares.
COMMENT ON FUNCTION sync_resource_permissions_on_share IS 'Placeholder for future JSONB sync automation';
-- ============================================================================
-- SECTION 7: Helper Functions for Application Layer
-- ============================================================================
-- Function to get all resources shared with a team
CREATE OR REPLACE FUNCTION get_team_resources(p_team_id UUID, p_resource_type VARCHAR DEFAULT NULL)
RETURNS TABLE (
resource_id UUID,
resource_type VARCHAR,
shared_by UUID,
created_at TIMESTAMP,
member_count BIGINT
) AS $$
BEGIN
RETURN QUERY
SELECT
trs.resource_id,
trs.resource_type,
trs.shared_by,
trs.created_at,
COUNT(DISTINCT tm.user_id) as member_count
FROM team_resource_shares trs
JOIN team_memberships tm ON tm.team_id = trs.team_id
WHERE trs.team_id = p_team_id
AND (p_resource_type IS NULL OR trs.resource_type = p_resource_type)
AND tm.resource_permissions ? (trs.resource_type || ':' || trs.resource_id::text)
GROUP BY trs.resource_id, trs.resource_type, trs.shared_by, trs.created_at
ORDER BY trs.created_at DESC;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION get_team_resources IS 'Get all resources shared with a team, optionally filtered by resource type';
-- Function to check if a user has permission on a resource
CREATE OR REPLACE FUNCTION check_user_resource_permission(
p_user_id UUID,
p_resource_type VARCHAR,
p_resource_id UUID,
p_required_permission VARCHAR DEFAULT 'read'
)
RETURNS BOOLEAN AS $$
DECLARE
user_permission VARCHAR;
BEGIN
-- Get the user's permission from any team that has this resource
SELECT (ura.permission::text)
INTO user_permission
FROM user_resource_access ura
WHERE ura.user_id = p_user_id
AND ura.resource_type = p_resource_type
AND ura.resource_id = p_resource_id
LIMIT 1;
-- If no permission found, return false
IF user_permission IS NULL THEN
RETURN FALSE;
END IF;
-- Remove quotes from JSONB string value
user_permission := TRIM(BOTH '"' FROM user_permission);
-- Check permission level
IF p_required_permission = 'read' THEN
RETURN user_permission IN ('read', 'edit');
ELSIF p_required_permission = 'edit' THEN
RETURN user_permission = 'edit';
ELSE
RETURN FALSE;
END IF;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION check_user_resource_permission IS 'Check if user has required permission (read/edit) on a resource';
-- ============================================================================
-- SECTION 8: Migration Data (if needed)
-- ============================================================================
-- If there are any existing agents/datasets with visibility='team',
-- they would need to be migrated here. Since this is a fresh feature,
-- no data migration is needed.
-- ============================================================================
-- SECTION 9: Grant Permissions
-- ============================================================================
-- Grant appropriate permissions to application roles
-- Note: Adjust role names based on your PostgreSQL setup
-- GRANT SELECT, INSERT, UPDATE, DELETE ON team_resource_shares TO gt2_tenant_user;
-- GRANT SELECT ON user_resource_access TO gt2_tenant_user;
-- GRANT SELECT ON user_accessible_resources TO gt2_tenant_user;
-- GRANT EXECUTE ON FUNCTION get_team_resources TO gt2_tenant_user;
-- GRANT EXECUTE ON FUNCTION check_user_resource_permission TO gt2_tenant_user;
-- ============================================================================
-- SECTION 10: Verification Queries
-- ============================================================================
-- Verify table was created
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'team_resource_shares') THEN
RAISE NOTICE 'SUCCESS: team_resource_shares table created';
ELSE
RAISE EXCEPTION 'FAILURE: team_resource_shares table not found';
END IF;
IF EXISTS (SELECT 1 FROM information_schema.views WHERE table_name = 'user_resource_access') THEN
RAISE NOTICE 'SUCCESS: user_resource_access view created';
ELSE
RAISE EXCEPTION 'FAILURE: user_resource_access view not found';
END IF;
IF EXISTS (SELECT 1 FROM information_schema.views WHERE table_name = 'user_accessible_resources') THEN
RAISE NOTICE 'SUCCESS: user_accessible_resources view created';
ELSE
RAISE EXCEPTION 'FAILURE: user_accessible_resources view not found';
END IF;
RAISE NOTICE 'Migration T003 completed successfully!';
END $$;

View File

@@ -0,0 +1,78 @@
-- Migration T004: Update validate_resource_share Trigger Function
-- Purpose: Allow team owners and admins to share resources without requiring team membership
-- Dependencies: T003_team_resource_shares.sql
-- Author: GT 2.0 Development Team
-- Date: 2025-01-07
--
-- Changes:
-- - Add team owner bypass check (owners don't need team membership)
-- - Add admin/developer role bypass check (admins can share to any team)
-- - Preserve original team membership + share permission check for regular users
--
-- This migration is idempotent via CREATE OR REPLACE FUNCTION
SET search_path TO tenant_test_company;
CREATE OR REPLACE FUNCTION validate_resource_share()
RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
user_team_permission VARCHAR(20);
is_team_owner BOOLEAN;
user_role VARCHAR(50);
user_tenant_id UUID;
team_tenant_id UUID;
BEGIN
-- Check if user is team owner
SELECT (owner_id = NEW.shared_by), tenant_id INTO is_team_owner, team_tenant_id
FROM teams
WHERE id = NEW.team_id;
-- Allow team owners to share
IF is_team_owner THEN
RETURN NEW;
END IF;
-- Check if user is admin/developer (bypass membership requirement)
SELECT u.user_type, u.tenant_id INTO user_role, user_tenant_id
FROM users u
WHERE u.id = NEW.shared_by;
-- Allow admins/developers in the same tenant
IF user_role IN ('admin', 'developer', 'super_admin') AND user_tenant_id = team_tenant_id THEN
RETURN NEW;
END IF;
-- Check if the user has 'share' permission on the team
SELECT team_permission INTO user_team_permission
FROM team_memberships
WHERE team_id = NEW.team_id
AND user_id = NEW.shared_by;
IF user_team_permission IS NULL THEN
RAISE EXCEPTION 'User % is not a member of team %', NEW.shared_by, NEW.team_id;
END IF;
IF user_team_permission != 'share' THEN
RAISE EXCEPTION 'User % does not have share permission on team %', NEW.shared_by, NEW.team_id;
END IF;
RETURN NEW;
END;
$$;
-- Verification: Check that the function exists
DO $$
BEGIN
IF EXISTS (
SELECT 1 FROM pg_proc p
JOIN pg_namespace n ON p.pronamespace = n.oid
WHERE n.nspname = 'tenant_test_company'
AND p.proname = 'validate_resource_share'
) THEN
RAISE NOTICE 'SUCCESS: T004 migration completed - validate_resource_share function updated';
ELSE
RAISE EXCEPTION 'FAILED: T004 migration - validate_resource_share function not found';
END IF;
END $$;

View File

@@ -0,0 +1,214 @@
-- Migration T005: Team Observability System
-- Purpose: Add Observable member tracking for team-level activity monitoring
-- Dependencies: T003_team_resource_shares.sql
-- Author: GT 2.0 Development Team
-- Date: 2025-01-10
-- Set schema for tenant isolation
SET search_path TO tenant_test_company;
-- ============================================================================
-- SECTION 1: Add Observable Columns to team_memberships
-- ============================================================================
-- Add Observable status tracking columns
ALTER TABLE team_memberships
ADD COLUMN IF NOT EXISTS is_observable BOOLEAN DEFAULT FALSE,
ADD COLUMN IF NOT EXISTS observable_consent_status VARCHAR(20) DEFAULT 'none',
ADD COLUMN IF NOT EXISTS observable_consent_at TIMESTAMPTZ;
-- Add constraint for observable_consent_status values
ALTER TABLE team_memberships
ADD CONSTRAINT check_observable_consent_status
CHECK (observable_consent_status IN ('none', 'pending', 'approved', 'revoked'));
COMMENT ON COLUMN team_memberships.is_observable IS 'Member consents to team managers viewing their activity';
COMMENT ON COLUMN team_memberships.observable_consent_status IS 'Consent workflow status: none, pending, approved, revoked';
COMMENT ON COLUMN team_memberships.observable_consent_at IS 'Timestamp when Observable status was approved';
-- ============================================================================
-- SECTION 2: Extend team_permission to Include Manager Role
-- ============================================================================
-- Drop existing constraint if it exists (handles both explicit and auto-generated names)
ALTER TABLE team_memberships DROP CONSTRAINT IF EXISTS check_team_permission;
ALTER TABLE team_memberships DROP CONSTRAINT IF EXISTS team_memberships_team_permission_check;
-- Add updated constraint with 'manager' role
ALTER TABLE team_memberships
ADD CONSTRAINT check_team_permission
CHECK (team_permission IN ('read', 'share', 'manager'));
COMMENT ON COLUMN team_memberships.team_permission IS
'Team role: read=Member (view only), share=Contributor (can share resources), manager=Manager (can manage members + view Observable activity)';
-- ============================================================================
-- SECTION 3: Update Auto-Unshare Trigger for Manager Role
-- ============================================================================
-- Update trigger function to handle 'manager' role
CREATE OR REPLACE FUNCTION auto_unshare_on_permission_downgrade()
RETURNS TRIGGER AS $$
BEGIN
-- Clear resource_permissions when downgrading from share/manager to read
-- Manager and Contributor (share) can share resources
-- Member (read) cannot share resources
IF OLD.team_permission IN ('share', 'manager')
AND NEW.team_permission = 'read' THEN
NEW.resource_permissions := '{}'::jsonb;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION auto_unshare_on_permission_downgrade IS
'Clears resource_permissions when member is downgraded to read-only (Member role)';
-- ============================================================================
-- SECTION 4: Update Resource Share Validation for Manager Role
-- ============================================================================
-- Update validation function to allow managers to share
CREATE OR REPLACE FUNCTION validate_resource_share()
RETURNS TRIGGER AS $$
DECLARE
user_team_permission VARCHAR(20);
is_team_owner BOOLEAN;
user_role VARCHAR(50);
BEGIN
-- Get user's team permission
SELECT team_permission INTO user_team_permission
FROM team_memberships
WHERE team_id = NEW.team_id
AND user_id = NEW.shared_by;
-- Check if user is the team owner
SELECT EXISTS (
SELECT 1 FROM teams
WHERE id = NEW.team_id AND owner_id = NEW.shared_by
) INTO is_team_owner;
-- Get user's system role for admin bypass
SELECT role INTO user_role
FROM users
WHERE id = NEW.shared_by;
-- Allow if: owner, or has share/manager permission, or is admin/developer
IF is_team_owner THEN
RETURN NEW;
END IF;
IF user_role IN ('admin', 'developer') THEN
RETURN NEW;
END IF;
IF user_team_permission IS NULL THEN
RAISE EXCEPTION 'User % is not a member of team %', NEW.shared_by, NEW.team_id;
END IF;
IF user_team_permission NOT IN ('share', 'manager') THEN
RAISE EXCEPTION 'User % does not have permission to share resources (current permission: %)',
NEW.shared_by, user_team_permission;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION validate_resource_share IS
'Validates that only owners, managers, contributors (share), or admins can share resources to teams';
-- ============================================================================
-- SECTION 5: Performance Indexes
-- ============================================================================
-- Index for finding Observable members (used for activity queries)
CREATE INDEX IF NOT EXISTS idx_team_memberships_observable
ON team_memberships(team_id, is_observable, observable_consent_status)
WHERE is_observable = true AND observable_consent_status = 'approved';
-- Index for finding members by role (for permission checks)
CREATE INDEX IF NOT EXISTS idx_team_memberships_permission
ON team_memberships(team_id, team_permission);
COMMENT ON INDEX idx_team_memberships_observable IS
'Optimizes queries for Observable member activity (partial index for approved Observable members only)';
COMMENT ON INDEX idx_team_memberships_permission IS
'Optimizes role-based permission checks (finding managers, contributors, etc.)';
-- ============================================================================
-- SECTION 6: Helper Function - Get Observable Members
-- ============================================================================
CREATE OR REPLACE FUNCTION get_observable_members(p_team_id UUID)
RETURNS TABLE (
user_id UUID,
user_email TEXT,
user_name TEXT,
observable_since TIMESTAMPTZ
) AS $$
BEGIN
RETURN QUERY
SELECT
tm.user_id,
u.email::text as user_email,
u.full_name::text as user_name,
tm.observable_consent_at
FROM team_memberships tm
JOIN users u ON tm.user_id = u.id
WHERE tm.team_id = p_team_id
AND tm.is_observable = true
AND tm.observable_consent_status = 'approved'
AND tm.status = 'accepted'
ORDER BY tm.observable_consent_at DESC;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION get_observable_members IS
'Returns list of Observable team members with approved consent status';
-- ============================================================================
-- SECTION 7: Verification
-- ============================================================================
DO $$
DECLARE
observable_count INTEGER;
manager_count INTEGER;
BEGIN
-- Verify Observable columns exist
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'team_memberships'
AND column_name = 'is_observable'
) THEN
RAISE EXCEPTION 'FAILURE: is_observable column not created';
END IF;
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'team_memberships'
AND column_name = 'observable_consent_status'
) THEN
RAISE EXCEPTION 'FAILURE: observable_consent_status column not created';
END IF;
-- Verify indexes
IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_team_memberships_observable'
) THEN
RAISE EXCEPTION 'FAILURE: idx_team_memberships_observable index not created';
END IF;
-- Count Observable members (should be 0 initially)
SELECT COUNT(*) INTO observable_count
FROM team_memberships
WHERE is_observable = true;
RAISE NOTICE 'SUCCESS: Observable columns added (current Observable members: %)', observable_count;
RAISE NOTICE 'SUCCESS: team_permission constraint updated to support manager role';
RAISE NOTICE 'SUCCESS: Indexes created for Observable queries';
RAISE NOTICE 'Migration T005 completed successfully!';
END $$;

View File

@@ -0,0 +1,60 @@
-- Migration: T006_auth_logs
-- Description: Add authentication logging for user logins, logouts, and failed attempts
-- Date: 2025-11-17
-- Issue: #152
-- This migration creates the auth_logs table to track authentication events
-- for observability and security auditing purposes.
BEGIN;
-- Apply to existing tenant schemas
DO $$
DECLARE
tenant_schema TEXT;
BEGIN
FOR tenant_schema IN
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
LOOP
-- Create auth_logs table
EXECUTE format('
CREATE TABLE IF NOT EXISTS %I.auth_logs (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id TEXT NOT NULL,
email TEXT NOT NULL,
event_type TEXT NOT NULL CHECK (event_type IN (''login'', ''logout'', ''failed_login'')),
success BOOLEAN NOT NULL DEFAULT true,
failure_reason TEXT,
ip_address TEXT,
user_agent TEXT,
tenant_domain TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
metadata JSONB DEFAULT ''{}''::jsonb
)', tenant_schema);
-- Create indexes
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_user_id ON %I.auth_logs(user_id)', tenant_schema);
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_email ON %I.auth_logs(email)', tenant_schema);
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_event_type ON %I.auth_logs(event_type)', tenant_schema);
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_created_at ON %I.auth_logs(created_at DESC)', tenant_schema);
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_tenant_domain ON %I.auth_logs(tenant_domain)', tenant_schema);
EXECUTE format('CREATE INDEX IF NOT EXISTS idx_auth_logs_event_created ON %I.auth_logs(event_type, created_at DESC)', tenant_schema);
RAISE NOTICE 'Applied T006_auth_logs migration to schema: %', tenant_schema;
END LOOP;
END $$;
COMMIT;
-- Verification query
SELECT
n.nspname AS schema_name,
c.relname AS table_name,
pg_size_pretty(pg_total_relation_size(c.oid)) AS total_size
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.relname = 'auth_logs'
AND n.nspname LIKE 'tenant_%'
ORDER BY n.nspname;

View File

@@ -0,0 +1,61 @@
-- T007_optimize_queries.sql
-- Phase 1 Performance Optimization: Composite Indexes
-- Creates composite indexes for common query patterns to improve performance
-- Estimated improvement: 60-80% faster conversation and message queries
BEGIN;
-- Apply to all existing tenant schemas
DO $$
DECLARE
tenant_schema TEXT;
BEGIN
FOR tenant_schema IN
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
LOOP
-- Composite index for message queries
-- Optimizes: SELECT * FROM messages WHERE conversation_id = ? ORDER BY created_at
-- Common in: conversation_service.get_messages() with pagination
-- Impact: Covers both filter and sort in single index scan
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_messages_conversation_created
ON %I.messages
USING btree (conversation_id, created_at ASC)
', tenant_schema);
-- Composite index for conversation list queries
-- Optimizes: SELECT * FROM conversations WHERE user_id = ? AND is_archived = false ORDER BY updated_at DESC
-- Common in: conversation_service.list_conversations()
-- Impact: Enables index-only scan for conversation lists
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_conversations_user_updated
ON %I.conversations
USING btree (user_id, is_archived, updated_at DESC)
', tenant_schema);
RAISE NOTICE 'Applied T007 optimization indexes to schema: %', tenant_schema;
END LOOP;
END $$;
COMMIT;
-- Performance Notes:
-- - Both indexes support common access patterns in the application
-- - No schema changes - purely additive optimization
-- - Safe to run multiple times (IF NOT EXISTS)
-- - Note: CONCURRENTLY cannot be used inside DO $$ blocks
--
-- Rollback (if needed):
-- DO $$
-- DECLARE tenant_schema TEXT;
-- BEGIN
-- FOR tenant_schema IN
-- SELECT schema_name FROM information_schema.schemata
-- WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
-- LOOP
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_messages_conversation_created', tenant_schema);
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_conversations_user_updated', tenant_schema);
-- END LOOP;
-- END $$;

View File

@@ -0,0 +1,73 @@
-- T008_add_performance_indexes.sql
-- Performance optimization: Add missing FK indexes for agents, datasets, and team shares
-- Fixes: GitHub Issue #173 - Database Optimizations
-- Impact: 60-80% faster API response times by eliminating full table scans
BEGIN;
-- Apply to all existing tenant schemas
DO $$
DECLARE
tenant_schema TEXT;
BEGIN
FOR tenant_schema IN
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
LOOP
-- Index for conversations.agent_id FK
-- Optimizes: Queries filtering/joining conversations by agent
-- Common in: agent_service.py aggregations, dashboard stats
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_conversations_agent_id
ON %I.conversations
USING btree (agent_id)
', tenant_schema);
-- Index for documents.dataset_id FK
-- Optimizes: Queries filtering documents by dataset
-- Common in: dataset_service.py stats, document counts per dataset
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_documents_dataset_id
ON %I.documents
USING btree (dataset_id)
', tenant_schema);
-- Composite index for team_resource_shares lookup
-- Optimizes: get_resource_teams() queries by resource type and ID
-- Fixes N+1: Enables batch lookups for agent/dataset team shares
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_team_resource_shares_lookup
ON %I.team_resource_shares
USING btree (resource_type, resource_id)
', tenant_schema);
RAISE NOTICE 'Applied T008 performance indexes to schema: %', tenant_schema;
END LOOP;
END $$;
COMMIT;
-- Performance Notes:
-- - idx_conversations_agent_id: Required for agent-to-conversation joins
-- - idx_documents_dataset_id: Required for dataset-to-document joins
-- - idx_team_resource_shares_lookup: Enables batch team share lookups
-- - All indexes are additive (IF NOT EXISTS) - safe to run multiple times
--
-- Expected impact at scale:
-- - 1,000 users: 50-100ms queries → 5-15ms
-- - 10,000 users: 500-1500ms queries → 20-80ms
--
-- Rollback (if needed):
-- DO $$
-- DECLARE tenant_schema TEXT;
-- BEGIN
-- FOR tenant_schema IN
-- SELECT schema_name FROM information_schema.schemata
-- WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
-- LOOP
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_conversations_agent_id', tenant_schema);
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_documents_dataset_id', tenant_schema);
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_team_resource_shares_lookup', tenant_schema);
-- END LOOP;
-- END $$;

View File

@@ -0,0 +1,143 @@
-- T009_tenant_scoped_categories.sql
-- Tenant-Scoped Editable/Deletable Agent Categories
-- Issue: #215 - FR: Editable/Deletable Default Agent Categories
--
-- Changes:
-- 1. Creates categories table in each tenant schema
-- 2. Seeds default categories (General, Coding, Writing, etc.)
-- 3. Migrates existing per-user custom categories to tenant-scoped
--
-- Rollback: See bottom of file
BEGIN;
-- Apply to all existing tenant schemas
DO $$
DECLARE
tenant_schema TEXT;
BEGIN
FOR tenant_schema IN
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
LOOP
-- Create categories table
EXECUTE format('
CREATE TABLE IF NOT EXISTS %I.categories (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id UUID NOT NULL,
name VARCHAR(100) NOT NULL,
slug VARCHAR(100) NOT NULL,
description TEXT,
icon VARCHAR(10),
is_default BOOLEAN DEFAULT FALSE,
created_by UUID,
sort_order INTEGER DEFAULT 0,
is_deleted BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
CONSTRAINT fk_categories_tenant FOREIGN KEY (tenant_id)
REFERENCES %I.tenants(id) ON DELETE CASCADE,
CONSTRAINT fk_categories_created_by FOREIGN KEY (created_by)
REFERENCES %I.users(id) ON DELETE SET NULL,
CONSTRAINT uq_categories_tenant_slug UNIQUE (tenant_id, slug)
)
', tenant_schema, tenant_schema, tenant_schema);
-- Create indexes
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_categories_tenant_id
ON %I.categories(tenant_id)
', tenant_schema);
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_categories_slug
ON %I.categories(tenant_id, slug)
', tenant_schema);
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_categories_created_by
ON %I.categories(created_by)
', tenant_schema);
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_categories_is_deleted
ON %I.categories(is_deleted) WHERE is_deleted = FALSE
', tenant_schema);
-- Seed default categories for each tenant in this schema
EXECUTE format('
INSERT INTO %I.categories (tenant_id, name, slug, description, icon, is_default, sort_order)
SELECT
t.id,
c.name,
c.slug,
c.description,
c.icon,
TRUE,
c.sort_order
FROM %I.tenants t
CROSS JOIN (VALUES
(''General'', ''general'', ''All-purpose agent for various tasks'', NULL, 10),
(''Coding'', ''coding'', ''Programming and development assistance'', NULL, 20),
(''Writing'', ''writing'', ''Content creation and editing'', NULL, 30),
(''Analysis'', ''analysis'', ''Data analysis and insights'', NULL, 40),
(''Creative'', ''creative'', ''Creative projects and brainstorming'', NULL, 50),
(''Research'', ''research'', ''Research and fact-checking'', NULL, 60),
(''Business'', ''business'', ''Business strategy and operations'', NULL, 70),
(''Education'', ''education'', ''Teaching and learning assistance'', NULL, 80)
) AS c(name, slug, description, icon, sort_order)
ON CONFLICT (tenant_id, slug) DO NOTHING
', tenant_schema, tenant_schema);
-- Migrate existing per-user custom categories from users.preferences
-- Custom categories are stored as: preferences->'custom_categories' = [{"name": "...", "description": "..."}, ...]
EXECUTE format('
INSERT INTO %I.categories (tenant_id, name, slug, description, created_by, is_default, sort_order)
SELECT DISTINCT ON (u.tenant_id, lower(regexp_replace(cc.name, ''[^a-zA-Z0-9]+'', ''-'', ''g'')))
u.tenant_id,
cc.name,
lower(regexp_replace(cc.name, ''[^a-zA-Z0-9]+'', ''-'', ''g'')),
COALESCE(cc.description, ''Custom category''),
u.id,
FALSE,
100 + ROW_NUMBER() OVER (PARTITION BY u.tenant_id ORDER BY cc.name)
FROM %I.users u
CROSS JOIN LATERAL jsonb_array_elements(
COALESCE(u.preferences->''custom_categories'', ''[]''::jsonb)
) AS cc_json
CROSS JOIN LATERAL (
SELECT
cc_json->>''name'' AS name,
cc_json->>''description'' AS description
) AS cc
WHERE cc.name IS NOT NULL AND cc.name != ''''
ON CONFLICT (tenant_id, slug) DO NOTHING
', tenant_schema, tenant_schema);
RAISE NOTICE 'Applied T009 categories table to schema: %', tenant_schema;
END LOOP;
END $$;
COMMIT;
-- Verification query (run manually):
-- SELECT schema_name,
-- (SELECT COUNT(*) FROM information_schema.tables
-- WHERE table_schema = s.schema_name AND table_name = 'categories') as has_categories_table
-- FROM information_schema.schemata s
-- WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template';
-- Rollback (if needed):
-- DO $$
-- DECLARE tenant_schema TEXT;
-- BEGIN
-- FOR tenant_schema IN
-- SELECT schema_name FROM information_schema.schemata
-- WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
-- LOOP
-- EXECUTE format('DROP TABLE IF EXISTS %I.categories CASCADE', tenant_schema);
-- RAISE NOTICE 'Dropped categories table from schema: %', tenant_schema;
-- END LOOP;
-- END $$;