LightRAG/starter/migrations/002_add_generated_columns_fk.sql
Raphael MANSUY fe9b8ec02a
tests: stabilize integration tests + skip external services; fix multi-tenant API behavior and idempotency (#4)
* feat: Implement multi-tenant architecture with tenant and knowledge base models

- Added data models for tenants, knowledge bases, and related configurations.
- Introduced role and permission management for users in the multi-tenant system.
- Created a service layer for managing tenants and knowledge bases, including CRUD operations.
- Developed a tenant-aware instance manager for LightRAG with caching and isolation features.
- Added a migration script to transition existing workspace-based deployments to the new multi-tenant architecture.

* chore: ignore lightrag/api/webui/assets/ directory

* chore: stop tracking lightrag/api/webui/assets (ignore in .gitignore)

* feat: Initialize LightRAG Multi-Tenant Stack with PostgreSQL

- Added README.md for project overview, setup instructions, and architecture details.
- Created docker-compose.yml to define services: PostgreSQL, Redis, LightRAG API, and Web UI.
- Introduced env.example for environment variable configuration.
- Implemented init-postgres.sql for PostgreSQL schema initialization with multi-tenant support.
- Added reproduce_issue.py for testing default tenant access via API.

* feat: Enhance TenantSelector and update related components for improved multi-tenant support

* feat: Enhance testing capabilities and update documentation

- Updated Makefile to include new test commands for various modes (compatibility, isolation, multi-tenant, security, coverage, and dry-run).
- Modified API health check endpoint in Makefile to reflect new port configuration.
- Updated QUICK_START.md and README.md to reflect changes in service URLs and ports.
- Added environment variables for testing modes in env.example.
- Introduced run_all_tests.sh script to automate testing across different modes.
- Created conftest.py for pytest configuration, including database fixtures and mock services.
- Implemented database helper functions for streamlined database operations in tests.
- Added test collection hooks to skip tests based on the current MULTITENANT_MODE.

* feat: Implement multi-tenant support with demo mode enabled by default

- Added multi-tenant configuration to the environment and Docker setup.
- Created pre-configured demo tenants (acme-corp and techstart) for testing.
- Updated API endpoints to support tenant-specific data access.
- Enhanced Makefile commands for better service management and database operations.
- Introduced user-tenant membership system with role-based access control.
- Added comprehensive documentation for multi-tenant setup and usage.
- Fixed issues with document visibility in multi-tenant environments.
- Implemented necessary database migrations for user memberships and legacy support.

* feat(audit): Add final audit report for multi-tenant implementation

- Documented overall assessment, architecture overview, test results, security findings, and recommendations.
- Included detailed findings on critical security issues and architectural concerns.

fix(security): Implement security fixes based on audit findings

- Removed global RAG fallback and enforced strict tenant context.
- Configured super-admin access and required user authentication for tenant access.
- Cleared localStorage on logout and improved error handling in WebUI.

chore(logs): Create task logs for audit and security fixes implementation

- Documented actions, decisions, and next steps for both audit and security fixes.
- Summarized test results and remaining recommendations.

chore(scripts): Enhance development stack management scripts

- Added scripts for cleaning, starting, and stopping the development stack.
- Improved output messages and ensured graceful shutdown of services.

feat(starter): Initialize PostgreSQL with AGE extension support

- Created initialization scripts for PostgreSQL extensions including uuid-ossp, vector, and AGE.
- Ensured successful installation and verification of extensions.

* feat: Implement auto-select for first tenant and KB on initial load in WebUI

- Removed WEBUI_INITIAL_STATE_FIX.md as the issue is resolved.
- Added useTenantInitialization hook to automatically select the first available tenant and KB on app load.
- Integrated the new hook into the Root component of the WebUI.
- Updated RetrievalTesting component to ensure a KB is selected before allowing user interaction.
- Created end-to-end tests for multi-tenant isolation and real service interactions.
- Added scripts for starting, stopping, and cleaning the development stack.
- Enhanced API and tenant routes to support tenant-specific pipeline status initialization.
- Updated constants for backend URL to reflect the correct port.
- Improved error handling and logging in various components.

* feat: Add multi-tenant support with enhanced E2E testing scripts and client functionality

* update client

* Add integration and unit tests for multi-tenant API, models, security, and storage

- Implement integration tests for tenant and knowledge base management endpoints in `test_tenant_api_routes.py`.
- Create unit tests for tenant isolation, model validation, and role permissions in `test_tenant_models.py`.
- Add security tests to enforce role-based permissions and context validation in `test_tenant_security.py`.
- Develop tests for tenant-aware storage operations and context isolation in `test_tenant_storage_phase3.py`.

* feat(e2e): Implement OpenAI model support and database reset functionality

* Add comprehensive test suite for gpt-5-nano compatibility

- Introduced tests for parameter normalization, embeddings, and entity extraction.
- Implemented direct API testing for gpt-5-nano.
- Validated .env configuration loading and OpenAI API connectivity.
- Analyzed reasoning token overhead with various token limits.
- Documented test procedures and expected outcomes in README files.
- Ensured all tests pass for production readiness.

* kg(postgres_impl): ensure AGE extension is loaded in session and configure graph initialization

* dev: add hybrid dev helper scripts, Makefile, docker-compose.dev-db and local development docs

* feat(dev): add dev helper scripts and local development documentation for hybrid setup

* feat(multi-tenant): add detailed specifications and logs for multi-tenant improvements, including UX, backend handling, and ingestion pipeline

* feat(migration): add generated tenant/kb columns, indexes, triggers; drop unused tables; update schema and docs

* test(backward-compat): adapt tests to new StorageNameSpace/TenantService APIs (use concrete dummy storages)

* chore: multi-tenant and UX updates — docs, webui, storage, tenant service adjustments

* tests: stabilize integration tests + skip external services; fix multi-tenant API behavior and idempotency

- gpt5_nano_compatibility: add pytest-asyncio markers, skip when OPENAI key missing, prevent module-level asyncio.run collection, add conftest
- Ollama tests: add server availability check and skip markers; avoid pytest collection warnings by renaming helper classes
- Graph storage tests: rename interactive test functions to avoid pytest collection
- Document & Tenant routes: support external_ids for idempotency; ensure HTTPExceptions are re-raised
- LightRAG core: support external_ids in apipeline_enqueue_documents and idempotent logic
- Tests updated to match API changes (tenant routes & document routes)
- Add logs and scripts for inspection and audit
2025-12-04 16:04:21 +08:00

345 lines
13 KiB
PL/PgSQL

-- ============================================================================
-- LightRAG Multi-Tenant Schema Migration - Complete Implementation
-- Version: 2.0.0 (Consolidated)
-- Date: December 4, 2025
-- Purpose: Add generated columns, indexes, and auto-sync triggers to LIGHTRAG_* tables
--
-- This script implements the HYBRID APPROACH recommended by the audit:
-- - Keep LIGHTRAG_* tables as the authoritative storage
-- - Add generated columns for tenant_id and kb_id extraction from workspace
-- - Add indexes for query performance
-- - Add triggers to auto-register tenants/KBs
--
-- Usage:
-- PGPASSWORD=lightrag123 psql -h localhost -p 15432 -U lightrag -d lightrag_multitenant -f 002_add_generated_columns_fk.sql
-- ============================================================================
BEGIN;
-- ============================================================================
-- STEP 0: Create schema_migrations table if not exists
-- ============================================================================
CREATE TABLE IF NOT EXISTS schema_migrations (
version VARCHAR(50) PRIMARY KEY,
description TEXT,
status VARCHAR(20) DEFAULT 'applied',
applied_at TIMESTAMP DEFAULT NOW()
);
-- ============================================================================
-- STEP 1: Add generated columns to all LIGHTRAG_* tables
-- These columns auto-extract tenant_id and kb_id from workspace column
-- ============================================================================
-- LIGHTRAG_DOC_FULL
ALTER TABLE lightrag_doc_full
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_doc_full
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_DOC_CHUNKS
ALTER TABLE lightrag_doc_chunks
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_doc_chunks
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_DOC_STATUS
ALTER TABLE lightrag_doc_status
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_doc_status
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_VDB_CHUNKS
ALTER TABLE lightrag_vdb_chunks
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_vdb_chunks
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_VDB_ENTITY
ALTER TABLE lightrag_vdb_entity
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_vdb_entity
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_VDB_RELATION
ALTER TABLE lightrag_vdb_relation
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_vdb_relation
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_FULL_ENTITIES
ALTER TABLE lightrag_full_entities
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_full_entities
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_FULL_RELATIONS
ALTER TABLE lightrag_full_relations
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_full_relations
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- LIGHTRAG_LLM_CACHE
ALTER TABLE lightrag_llm_cache
ADD COLUMN IF NOT EXISTS tenant_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 1)
ELSE workspace
END
) STORED;
ALTER TABLE lightrag_llm_cache
ADD COLUMN IF NOT EXISTS kb_id VARCHAR(255) GENERATED ALWAYS AS (
CASE
WHEN workspace LIKE '%:%' THEN SPLIT_PART(workspace, ':', 2)
ELSE 'default'
END
) STORED;
-- ============================================================================
-- STEP 2: Add performance indexes on tenant_id and kb_id columns
-- ============================================================================
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_full_tenant ON lightrag_doc_full(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_full_tenant_kb ON lightrag_doc_full(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_chunks_tenant ON lightrag_doc_chunks(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_chunks_tenant_kb ON lightrag_doc_chunks(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_status_tenant ON lightrag_doc_status(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_doc_status_tenant_kb ON lightrag_doc_status(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_chunks_tenant ON lightrag_vdb_chunks(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_chunks_tenant_kb ON lightrag_vdb_chunks(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_entity_tenant ON lightrag_vdb_entity(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_entity_tenant_kb ON lightrag_vdb_entity(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_relation_tenant ON lightrag_vdb_relation(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_vdb_relation_tenant_kb ON lightrag_vdb_relation(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_full_entities_tenant ON lightrag_full_entities(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_full_entities_tenant_kb ON lightrag_full_entities(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_full_relations_tenant ON lightrag_full_relations(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_full_relations_tenant_kb ON lightrag_full_relations(tenant_id, kb_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_llm_cache_tenant ON lightrag_llm_cache(tenant_id);
CREATE INDEX IF NOT EXISTS idx_lightrag_llm_cache_tenant_kb ON lightrag_llm_cache(tenant_id, kb_id);
-- ============================================================================
-- STEP 3: Create auto-sync trigger function
-- This automatically registers tenants and knowledge bases when data is inserted
-- ============================================================================
CREATE OR REPLACE FUNCTION sync_tenant_from_workspace()
RETURNS TRIGGER AS $$
DECLARE
v_tenant_id VARCHAR(255);
v_kb_id VARCHAR(255);
BEGIN
-- Extract tenant_id and kb_id from workspace
v_tenant_id := SPLIT_PART(NEW.workspace, ':', 1);
v_kb_id := SPLIT_PART(NEW.workspace, ':', 2);
-- Skip if workspace doesn't contain colon (old format)
IF v_kb_id = '' OR v_kb_id IS NULL THEN
RETURN NEW;
END IF;
-- Insert tenant if not exists (use tenant_id column, not id)
INSERT INTO tenants (tenant_id, name, created_at, updated_at)
VALUES (v_tenant_id, v_tenant_id, NOW(), NOW())
ON CONFLICT (tenant_id) DO NOTHING;
-- Insert knowledge base if not exists
INSERT INTO knowledge_bases (tenant_id, kb_id, name, created_at, updated_at)
VALUES (v_tenant_id, v_kb_id, v_kb_id, NOW(), NOW())
ON CONFLICT (tenant_id, kb_id) DO NOTHING;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- ============================================================================
-- STEP 4: Add triggers to all LIGHTRAG_* tables
-- ============================================================================
DROP TRIGGER IF EXISTS trg_sync_tenant_doc_full ON lightrag_doc_full;
CREATE TRIGGER trg_sync_tenant_doc_full
BEFORE INSERT OR UPDATE ON lightrag_doc_full
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_doc_chunks ON lightrag_doc_chunks;
CREATE TRIGGER trg_sync_tenant_doc_chunks
BEFORE INSERT OR UPDATE ON lightrag_doc_chunks
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_doc_status ON lightrag_doc_status;
CREATE TRIGGER trg_sync_tenant_doc_status
BEFORE INSERT OR UPDATE ON lightrag_doc_status
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_vdb_chunks ON lightrag_vdb_chunks;
CREATE TRIGGER trg_sync_tenant_vdb_chunks
BEFORE INSERT OR UPDATE ON lightrag_vdb_chunks
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_vdb_entity ON lightrag_vdb_entity;
CREATE TRIGGER trg_sync_tenant_vdb_entity
BEFORE INSERT OR UPDATE ON lightrag_vdb_entity
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_vdb_relation ON lightrag_vdb_relation;
CREATE TRIGGER trg_sync_tenant_vdb_relation
BEFORE INSERT OR UPDATE ON lightrag_vdb_relation
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_full_entities ON lightrag_full_entities;
CREATE TRIGGER trg_sync_tenant_full_entities
BEFORE INSERT OR UPDATE ON lightrag_full_entities
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_full_relations ON lightrag_full_relations;
CREATE TRIGGER trg_sync_tenant_full_relations
BEFORE INSERT OR UPDATE ON lightrag_full_relations
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
DROP TRIGGER IF EXISTS trg_sync_tenant_llm_cache ON lightrag_llm_cache;
CREATE TRIGGER trg_sync_tenant_llm_cache
BEFORE INSERT OR UPDATE ON lightrag_llm_cache
FOR EACH ROW EXECUTE FUNCTION sync_tenant_from_workspace();
-- ============================================================================
-- STEP 5: Create user_tenant_memberships table for RBAC
-- ============================================================================
CREATE TABLE IF NOT EXISTS user_tenant_memberships (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id VARCHAR(255) NOT NULL,
tenant_id VARCHAR(255) NOT NULL REFERENCES tenants(tenant_id) ON DELETE CASCADE,
role VARCHAR(50) NOT NULL DEFAULT 'viewer',
permissions JSONB DEFAULT '[]'::jsonb,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
UNIQUE(user_id, tenant_id),
CONSTRAINT valid_role CHECK (role IN ('owner', 'admin', 'editor', 'viewer'))
);
CREATE INDEX IF NOT EXISTS idx_user_memberships_user ON user_tenant_memberships(user_id);
CREATE INDEX IF NOT EXISTS idx_user_memberships_tenant ON user_tenant_memberships(tenant_id);
-- ============================================================================
-- STEP 6: Record migrations
-- ============================================================================
INSERT INTO schema_migrations (version, description, status, applied_at) VALUES
('1.0.0', 'Initial schema with LIGHTRAG_* tables', 'applied', '2025-12-03 00:00:00'),
('2.0.0', 'Add generated columns (tenant_id, kb_id) and indexes to LIGHTRAG_* tables', 'applied', NOW()),
('2.1.0', 'Add auto-sync trigger for tenant/KB registration', 'applied', NOW()),
('2.2.0', 'Create user_tenant_memberships table for RBAC', 'applied', NOW())
ON CONFLICT (version) DO UPDATE SET status = 'applied', applied_at = NOW();
COMMIT;
-- ============================================================================
-- Verification
-- ============================================================================
-- Show all migrations
SELECT version, description, status, applied_at FROM schema_migrations ORDER BY version;
-- Show table count
SELECT COUNT(*) as table_count FROM pg_tables WHERE schemaname = 'public';
-- Show sample data with generated columns
SELECT workspace, tenant_id, kb_id FROM lightrag_doc_full LIMIT 1;