1144 lines
33 KiB
Markdown
1144 lines
33 KiB
Markdown
# Database Migration Strategy: Single-Tenant to Multi-Tenant
|
|
|
|
## Table of Contents
|
|
|
|
1. [Migration Overview](#migration-overview)
|
|
2. [Pre-Migration Checklist](#pre-migration-checklist)
|
|
3. [Database Migration Steps](#database-migration-steps)
|
|
4. [EF Core Migrations](#ef-core-migrations)
|
|
5. [Code Migration Steps](#code-migration-steps)
|
|
6. [Testing Migration](#testing-migration)
|
|
7. [Deployment Plan](#deployment-plan)
|
|
8. [Rollback Plan](#rollback-plan)
|
|
9. [Post-Migration Validation](#post-migration-validation)
|
|
|
|
---
|
|
|
|
## Migration Overview
|
|
|
|
### Objective
|
|
|
|
Transform ColaFlow from a single-tenant system to a **multi-tenant system** with:
|
|
- Tenant isolation via `tenant_id` column in all tables
|
|
- Default tenant created for existing data
|
|
- Zero data loss
|
|
- Minimal downtime
|
|
|
|
### Strategy
|
|
|
|
**Approach**: Create default tenant and migrate all existing data to it
|
|
|
|
```
|
|
Single-Tenant System (Before)
|
|
┌──────────────────┐
|
|
│ users │
|
|
│ - id │
|
|
│ - email │
|
|
│ - password_hash │
|
|
└──────────────────┘
|
|
|
|
Multi-Tenant System (After)
|
|
┌──────────────────┐ ┌──────────────────┐
|
|
│ tenants │ │ users │
|
|
│ - id │◄─────│ - id │
|
|
│ - name │ │ - tenant_id (FK)│
|
|
│ - slug │ │ - email │
|
|
└──────────────────┘ │ - password_hash │
|
|
└──────────────────┘
|
|
```
|
|
|
|
### Timeline
|
|
|
|
| Phase | Duration | Description |
|
|
|-------|----------|-------------|
|
|
| **Phase 1: Preparation** | 1 day | Backup, validation, test environment |
|
|
| **Phase 2: Database Migration** | 2-3 hours | Execute SQL scripts, create default tenant |
|
|
| **Phase 3: Code Deployment** | 1 hour | Deploy updated application code |
|
|
| **Phase 4: Validation** | 2 hours | Smoke tests, data validation |
|
|
| **Phase 5: Monitoring** | 1 week | Monitor production for issues |
|
|
|
|
**Total Expected Downtime**: 30-60 minutes (during Phase 2)
|
|
|
|
---
|
|
|
|
## Pre-Migration Checklist
|
|
|
|
### ✅ Before Starting Migration
|
|
|
|
- [ ] **Full database backup** completed and verified
|
|
- [ ] **Test environment** migration completed successfully
|
|
- [ ] **All tests passing** in test environment
|
|
- [ ] **Migration scripts** reviewed and approved
|
|
- [ ] **Rollback scripts** prepared and tested
|
|
- [ ] **Team notified** of maintenance window
|
|
- [ ] **Users notified** of scheduled downtime
|
|
- [ ] **Monitoring** alerts configured
|
|
- [ ] **Database connection strings** updated in configuration
|
|
- [ ] **EF Core migrations** generated and reviewed
|
|
|
|
### ⚠️ Migration Risks
|
|
|
|
| Risk | Impact | Mitigation |
|
|
|------|--------|------------|
|
|
| Data loss | Critical | Full backup before migration |
|
|
| Extended downtime | High | Test migration in staging first |
|
|
| Foreign key violations | High | Disable FK checks during migration |
|
|
| NULL constraint violations | Medium | Fill tenant_id before setting NOT NULL |
|
|
| Performance degradation | Medium | Add indexes after migration |
|
|
| Application errors | High | Deploy code and DB together |
|
|
|
|
---
|
|
|
|
## Database Migration Steps
|
|
|
|
### Step 1: Create Tenants Table
|
|
|
|
```sql
|
|
-- Create tenants table
|
|
CREATE TABLE tenants (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
name VARCHAR(100) NOT NULL,
|
|
slug VARCHAR(50) NOT NULL UNIQUE,
|
|
status INT NOT NULL DEFAULT 1, -- 1=Active, 2=Suspended, 3=Cancelled
|
|
plan INT NOT NULL DEFAULT 1, -- 1=Free, 2=Pro, 3=Enterprise
|
|
|
|
-- SSO Configuration (stored as JSONB)
|
|
sso_config JSONB NULL,
|
|
|
|
-- Limits
|
|
max_users INT NOT NULL DEFAULT 5,
|
|
max_projects INT NOT NULL DEFAULT 3,
|
|
max_storage_gb INT NOT NULL DEFAULT 2,
|
|
|
|
-- Status tracking
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NULL,
|
|
suspended_at TIMESTAMP NULL,
|
|
suspension_reason TEXT NULL,
|
|
|
|
CONSTRAINT chk_slug_format CHECK (slug ~ '^[a-z0-9]+(?:-[a-z0-9]+)*$')
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_tenants_slug ON tenants(slug);
|
|
CREATE INDEX idx_tenants_status ON tenants(status);
|
|
CREATE INDEX idx_tenants_plan ON tenants(plan);
|
|
|
|
-- Comments
|
|
COMMENT ON TABLE tenants IS 'Multi-tenant organizations';
|
|
COMMENT ON COLUMN tenants.slug IS 'URL-safe identifier (used in subdomains)';
|
|
```
|
|
|
|
### Step 2: Create Default Tenant
|
|
|
|
```sql
|
|
-- Insert default tenant for existing data
|
|
-- IMPORTANT: Save this UUID - you'll need it for data migration
|
|
INSERT INTO tenants (
|
|
id,
|
|
name,
|
|
slug,
|
|
status,
|
|
plan,
|
|
max_users,
|
|
max_projects,
|
|
max_storage_gb,
|
|
created_at
|
|
) VALUES (
|
|
'ffffffff-ffff-ffff-ffff-ffffffffffff', -- Use a well-known UUID for default tenant
|
|
'Default Organization',
|
|
'default',
|
|
1, -- Active
|
|
3, -- Enterprise
|
|
999999,
|
|
999999,
|
|
999999,
|
|
NOW()
|
|
);
|
|
|
|
-- Verify creation
|
|
SELECT * FROM tenants WHERE slug = 'default';
|
|
```
|
|
|
|
### Step 3: Add tenant_id Columns (Allow NULL Initially)
|
|
|
|
```sql
|
|
-- Users table
|
|
ALTER TABLE users ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE users ADD CONSTRAINT fk_users_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Add tenant_id to ALL business tables
|
|
-- Projects
|
|
ALTER TABLE projects ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE projects ADD CONSTRAINT fk_projects_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Issues
|
|
ALTER TABLE issues ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE issues ADD CONSTRAINT fk_issues_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Epics
|
|
ALTER TABLE epics ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE epics ADD CONSTRAINT fk_epics_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Sprints
|
|
ALTER TABLE sprints ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE sprints ADD CONSTRAINT fk_sprints_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Issue Comments
|
|
ALTER TABLE issue_comments ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE issue_comments ADD CONSTRAINT fk_issue_comments_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Attachments
|
|
ALTER TABLE attachments ADD COLUMN tenant_id UUID NULL;
|
|
ALTER TABLE attachments ADD CONSTRAINT fk_attachments_tenant
|
|
FOREIGN KEY (tenant_id) REFERENCES tenants(id) ON DELETE CASCADE;
|
|
|
|
-- Add to ALL other business tables...
|
|
```
|
|
|
|
### Step 4: Migrate Existing Data to Default Tenant
|
|
|
|
```sql
|
|
-- Set the default tenant UUID
|
|
DO $$
|
|
DECLARE
|
|
default_tenant_id UUID := 'ffffffff-ffff-ffff-ffff-ffffffffffff';
|
|
BEGIN
|
|
-- Update users
|
|
UPDATE users SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % users', (SELECT COUNT(*) FROM users WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update projects
|
|
UPDATE projects SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % projects', (SELECT COUNT(*) FROM projects WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update issues
|
|
UPDATE issues SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % issues', (SELECT COUNT(*) FROM issues WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update epics
|
|
UPDATE epics SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % epics', (SELECT COUNT(*) FROM epics WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update sprints
|
|
UPDATE sprints SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % sprints', (SELECT COUNT(*) FROM sprints WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update issue_comments
|
|
UPDATE issue_comments SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % issue_comments', (SELECT COUNT(*) FROM issue_comments WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update attachments
|
|
UPDATE attachments SET tenant_id = default_tenant_id WHERE tenant_id IS NULL;
|
|
RAISE NOTICE 'Updated % attachments', (SELECT COUNT(*) FROM attachments WHERE tenant_id = default_tenant_id);
|
|
|
|
-- Update ALL other tables...
|
|
END $$;
|
|
```
|
|
|
|
### Step 5: Validate Data Migration
|
|
|
|
```sql
|
|
-- Check for NULL tenant_id values (should be 0)
|
|
SELECT 'users' AS table_name, COUNT(*) AS null_count FROM users WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'projects', COUNT(*) FROM projects WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'issues', COUNT(*) FROM issues WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'epics', COUNT(*) FROM epics WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'sprints', COUNT(*) FROM sprints WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'issue_comments', COUNT(*) FROM issue_comments WHERE tenant_id IS NULL
|
|
UNION ALL
|
|
SELECT 'attachments', COUNT(*) FROM attachments WHERE tenant_id IS NULL;
|
|
|
|
-- Expected output: All counts should be 0
|
|
```
|
|
|
|
### Step 6: Set tenant_id as NOT NULL
|
|
|
|
```sql
|
|
-- Now make tenant_id NOT NULL (all rows have values)
|
|
ALTER TABLE users ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE projects ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE issues ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE epics ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE sprints ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE issue_comments ALTER COLUMN tenant_id SET NOT NULL;
|
|
ALTER TABLE attachments ALTER COLUMN tenant_id SET NOT NULL;
|
|
|
|
-- Add to ALL other tables...
|
|
```
|
|
|
|
### Step 7: Create Composite Indexes
|
|
|
|
```sql
|
|
-- CRITICAL: These indexes ensure query performance
|
|
|
|
-- Users
|
|
CREATE INDEX idx_users_tenant_id ON users(tenant_id);
|
|
CREATE INDEX idx_users_tenant_email ON users(tenant_id, email);
|
|
CREATE INDEX idx_users_tenant_status ON users(tenant_id, is_active);
|
|
|
|
-- Projects
|
|
CREATE INDEX idx_projects_tenant_id ON projects(tenant_id);
|
|
CREATE INDEX idx_projects_tenant_key ON projects(tenant_id, key);
|
|
CREATE INDEX idx_projects_tenant_status ON projects(tenant_id, status);
|
|
CREATE INDEX idx_projects_tenant_created ON projects(tenant_id, created_at DESC);
|
|
|
|
-- Issues
|
|
CREATE INDEX idx_issues_tenant_id ON issues(tenant_id);
|
|
CREATE INDEX idx_issues_tenant_project ON issues(tenant_id, project_id);
|
|
CREATE INDEX idx_issues_tenant_status ON issues(tenant_id, status);
|
|
CREATE INDEX idx_issues_tenant_assignee ON issues(tenant_id, assignee_id);
|
|
CREATE INDEX idx_issues_tenant_created ON issues(tenant_id, created_at DESC);
|
|
|
|
-- Epics
|
|
CREATE INDEX idx_epics_tenant_id ON epics(tenant_id);
|
|
CREATE INDEX idx_epics_tenant_project ON epics(tenant_id, project_id);
|
|
|
|
-- Sprints
|
|
CREATE INDEX idx_sprints_tenant_id ON sprints(tenant_id);
|
|
CREATE INDEX idx_sprints_tenant_project ON sprints(tenant_id, project_id);
|
|
|
|
-- Issue Comments
|
|
CREATE INDEX idx_issue_comments_tenant_id ON issue_comments(tenant_id);
|
|
CREATE INDEX idx_issue_comments_tenant_issue ON issue_comments(tenant_id, issue_id);
|
|
|
|
-- Attachments
|
|
CREATE INDEX idx_attachments_tenant_id ON attachments(tenant_id);
|
|
|
|
-- Add indexes to ALL other tables...
|
|
```
|
|
|
|
### Step 8: Update Unique Constraints
|
|
|
|
```sql
|
|
-- Update unique constraints to include tenant_id
|
|
|
|
-- Users: email should be unique per tenant (not globally)
|
|
ALTER TABLE users DROP CONSTRAINT IF EXISTS users_email_key;
|
|
ALTER TABLE users ADD CONSTRAINT uq_users_tenant_email UNIQUE (tenant_id, email);
|
|
|
|
-- Projects: key should be unique per tenant
|
|
ALTER TABLE projects DROP CONSTRAINT IF EXISTS projects_key_key;
|
|
ALTER TABLE projects ADD CONSTRAINT uq_projects_tenant_key UNIQUE (tenant_id, key);
|
|
|
|
-- Add similar constraints for other tables...
|
|
```
|
|
|
|
### Step 9: Add SSO-Related Columns to Users Table
|
|
|
|
```sql
|
|
-- Add SSO fields to users table
|
|
ALTER TABLE users ADD COLUMN auth_provider INT NOT NULL DEFAULT 1; -- 1=Local
|
|
ALTER TABLE users ADD COLUMN external_user_id VARCHAR(255) NULL;
|
|
ALTER TABLE users ADD COLUMN external_email VARCHAR(255) NULL;
|
|
|
|
-- Add unique constraint for SSO users
|
|
CREATE UNIQUE INDEX idx_users_tenant_provider_external
|
|
ON users(tenant_id, auth_provider, external_user_id)
|
|
WHERE external_user_id IS NOT NULL;
|
|
|
|
-- Add index for external lookups
|
|
CREATE INDEX idx_users_external_user_id
|
|
ON users(external_user_id)
|
|
WHERE external_user_id IS NOT NULL;
|
|
```
|
|
|
|
### Step 10: Create MCP Tokens Table
|
|
|
|
```sql
|
|
-- Create MCP tokens table
|
|
CREATE TABLE mcp_tokens (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
|
user_id UUID NULL REFERENCES users(id) ON DELETE SET NULL,
|
|
|
|
-- Token details
|
|
name VARCHAR(100) NOT NULL,
|
|
token_hash VARCHAR(255) NOT NULL UNIQUE,
|
|
permissions JSONB NOT NULL,
|
|
|
|
-- Status
|
|
status INT NOT NULL DEFAULT 1, -- 1=Active, 2=Expired, 3=Revoked
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NULL,
|
|
expires_at TIMESTAMP NULL,
|
|
revoked_at TIMESTAMP NULL,
|
|
revocation_reason TEXT NULL,
|
|
|
|
-- Usage tracking
|
|
last_used_at TIMESTAMP NULL,
|
|
usage_count INT NOT NULL DEFAULT 0,
|
|
|
|
-- Security
|
|
ip_whitelist JSONB NULL
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_mcp_tokens_tenant_id ON mcp_tokens(tenant_id);
|
|
CREATE INDEX idx_mcp_tokens_token_hash ON mcp_tokens(token_hash);
|
|
CREATE INDEX idx_mcp_tokens_tenant_status ON mcp_tokens(tenant_id, status);
|
|
CREATE INDEX idx_mcp_tokens_user_id ON mcp_tokens(user_id) WHERE user_id IS NOT NULL;
|
|
```
|
|
|
|
### Step 11: Create MCP Audit Logs Table
|
|
|
|
```sql
|
|
-- Create MCP audit logs table
|
|
CREATE TABLE mcp_audit_logs (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
|
token_id UUID NOT NULL REFERENCES mcp_tokens(id) ON DELETE CASCADE,
|
|
user_id UUID NULL REFERENCES users(id) ON DELETE SET NULL,
|
|
|
|
-- Request details
|
|
http_method VARCHAR(10) NOT NULL,
|
|
endpoint VARCHAR(500) NOT NULL,
|
|
request_body TEXT NULL,
|
|
|
|
-- Response details
|
|
status_code INT NOT NULL,
|
|
response_body TEXT NULL,
|
|
|
|
-- Security
|
|
ip_address VARCHAR(50) NOT NULL,
|
|
user_agent VARCHAR(500) NULL,
|
|
|
|
-- Timing
|
|
timestamp TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
duration_ms INT NOT NULL,
|
|
|
|
-- Error tracking
|
|
error_message TEXT NULL
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_mcp_audit_logs_tenant_id ON mcp_audit_logs(tenant_id);
|
|
CREATE INDEX idx_mcp_audit_logs_token_id ON mcp_audit_logs(token_id);
|
|
CREATE INDEX idx_mcp_audit_logs_timestamp ON mcp_audit_logs(timestamp DESC);
|
|
CREATE INDEX idx_mcp_audit_logs_tenant_timestamp ON mcp_audit_logs(tenant_id, timestamp DESC);
|
|
```
|
|
|
|
---
|
|
|
|
## EF Core Migrations
|
|
|
|
### Generate Migrations
|
|
|
|
```bash
|
|
# Navigate to Infrastructure project
|
|
cd src/ColaFlow.Infrastructure
|
|
|
|
# Generate migration for multi-tenancy
|
|
dotnet ef migrations add AddMultiTenancySupport \
|
|
--context ApplicationDbContext \
|
|
--output-dir Persistence/Migrations
|
|
|
|
# Review generated migration files
|
|
# Edit if necessary to match manual SQL scripts
|
|
|
|
# Apply migration (PRODUCTION)
|
|
dotnet ef database update --context ApplicationDbContext
|
|
```
|
|
|
|
### Migration File Example
|
|
|
|
**File**: `src/ColaFlow.Infrastructure/Persistence/Migrations/YYYYMMDDHHMMSS_AddMultiTenancySupport.cs`
|
|
|
|
```csharp
|
|
using Microsoft.EntityFrameworkCore.Migrations;
|
|
|
|
public partial class AddMultiTenancySupport : Migration
|
|
{
|
|
protected override void Up(MigrationBuilder migrationBuilder)
|
|
{
|
|
// 1. Create tenants table
|
|
migrationBuilder.CreateTable(
|
|
name: "tenants",
|
|
columns: table => new
|
|
{
|
|
id = table.Column<Guid>(nullable: false),
|
|
name = table.Column<string>(maxLength: 100, nullable: false),
|
|
slug = table.Column<string>(maxLength: 50, nullable: false),
|
|
status = table.Column<int>(nullable: false, defaultValue: 1),
|
|
plan = table.Column<int>(nullable: false, defaultValue: 1),
|
|
sso_config = table.Column<string>(type: "jsonb", nullable: true),
|
|
max_users = table.Column<int>(nullable: false, defaultValue: 5),
|
|
max_projects = table.Column<int>(nullable: false, defaultValue: 3),
|
|
max_storage_gb = table.Column<int>(nullable: false, defaultValue: 2),
|
|
created_at = table.Column<DateTime>(nullable: false, defaultValueSql: "NOW()"),
|
|
updated_at = table.Column<DateTime>(nullable: true),
|
|
suspended_at = table.Column<DateTime>(nullable: true),
|
|
suspension_reason = table.Column<string>(nullable: true)
|
|
},
|
|
constraints: table =>
|
|
{
|
|
table.PrimaryKey("PK_tenants", x => x.id);
|
|
table.CheckConstraint("chk_slug_format", "slug ~ '^[a-z0-9]+(?:-[a-z0-9]+)*$'");
|
|
});
|
|
|
|
migrationBuilder.CreateIndex(
|
|
name: "idx_tenants_slug",
|
|
table: "tenants",
|
|
column: "slug",
|
|
unique: true);
|
|
|
|
// 2. Insert default tenant
|
|
migrationBuilder.Sql(@"
|
|
INSERT INTO tenants (id, name, slug, status, plan, max_users, max_projects, max_storage_gb, created_at)
|
|
VALUES ('ffffffff-ffff-ffff-ffff-ffffffffffff', 'Default Organization', 'default', 1, 3, 999999, 999999, 999999, NOW());
|
|
");
|
|
|
|
// 3. Add tenant_id columns (nullable first)
|
|
migrationBuilder.AddColumn<Guid>(
|
|
name: "tenant_id",
|
|
table: "users",
|
|
nullable: true);
|
|
|
|
migrationBuilder.AddColumn<Guid>(
|
|
name: "tenant_id",
|
|
table: "projects",
|
|
nullable: true);
|
|
|
|
// ... add to all tables
|
|
|
|
// 4. Migrate existing data
|
|
migrationBuilder.Sql(@"
|
|
UPDATE users SET tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff' WHERE tenant_id IS NULL;
|
|
UPDATE projects SET tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff' WHERE tenant_id IS NULL;
|
|
");
|
|
|
|
// 5. Make tenant_id NOT NULL
|
|
migrationBuilder.AlterColumn<Guid>(
|
|
name: "tenant_id",
|
|
table: "users",
|
|
nullable: false);
|
|
|
|
migrationBuilder.AlterColumn<Guid>(
|
|
name: "tenant_id",
|
|
table: "projects",
|
|
nullable: false);
|
|
|
|
// 6. Add foreign keys
|
|
migrationBuilder.CreateIndex(
|
|
name: "idx_users_tenant_id",
|
|
table: "users",
|
|
column: "tenant_id");
|
|
|
|
migrationBuilder.AddForeignKey(
|
|
name: "fk_users_tenant",
|
|
table: "users",
|
|
column: "tenant_id",
|
|
principalTable: "tenants",
|
|
principalColumn: "id",
|
|
onDelete: ReferentialAction.Cascade);
|
|
|
|
// ... add foreign keys for all tables
|
|
|
|
// 7. Update unique constraints
|
|
migrationBuilder.DropIndex(
|
|
name: "ix_users_email",
|
|
table: "users");
|
|
|
|
migrationBuilder.CreateIndex(
|
|
name: "uq_users_tenant_email",
|
|
table: "users",
|
|
columns: new[] { "tenant_id", "email" },
|
|
unique: true);
|
|
|
|
// 8. Add SSO columns
|
|
migrationBuilder.AddColumn<int>(
|
|
name: "auth_provider",
|
|
table: "users",
|
|
nullable: false,
|
|
defaultValue: 1);
|
|
|
|
migrationBuilder.AddColumn<string>(
|
|
name: "external_user_id",
|
|
table: "users",
|
|
maxLength: 255,
|
|
nullable: true);
|
|
|
|
// 9. Create MCP tables
|
|
// ... (mcp_tokens, mcp_audit_logs)
|
|
}
|
|
|
|
protected override void Down(MigrationBuilder migrationBuilder)
|
|
{
|
|
// Rollback logic (see Rollback Plan section)
|
|
}
|
|
}
|
|
```
|
|
|
|
---
|
|
|
|
## Code Migration Steps
|
|
|
|
### Step 1: Update All Domain Entities
|
|
|
|
Add `TenantId` property to all aggregate roots:
|
|
|
|
```csharp
|
|
// Before
|
|
public sealed class Project : AggregateRoot<ProjectId>
|
|
{
|
|
public ProjectId Id { get; private set; }
|
|
// ... other properties
|
|
}
|
|
|
|
// After
|
|
public sealed class Project : AggregateRoot<ProjectId>, IHasTenant
|
|
{
|
|
public ProjectId Id { get; private set; }
|
|
public TenantId TenantId { get; set; } // NEW
|
|
// ... other properties
|
|
}
|
|
```
|
|
|
|
**Apply to**:
|
|
- User
|
|
- Project
|
|
- Epic
|
|
- Issue
|
|
- Sprint
|
|
- IssueComment
|
|
- Attachment
|
|
- All other entities
|
|
|
|
### Step 2: Update All Commands/Queries
|
|
|
|
Ensure all commands/queries respect tenant context:
|
|
|
|
```csharp
|
|
// Before
|
|
public async Task<ProjectDto?> Handle(GetProjectByIdQuery request, CancellationToken cancellationToken)
|
|
{
|
|
var project = await _context.Projects
|
|
.FirstOrDefaultAsync(p => p.Id == request.ProjectId, cancellationToken);
|
|
// ...
|
|
}
|
|
|
|
// After (Global Query Filter automatically applies tenant filtering)
|
|
public async Task<ProjectDto?> Handle(GetProjectByIdQuery request, CancellationToken cancellationToken)
|
|
{
|
|
var project = await _context.Projects
|
|
.FirstOrDefaultAsync(p => p.Id == request.ProjectId, cancellationToken);
|
|
// Tenant filtering is automatic via EF Core Global Query Filter
|
|
// ...
|
|
}
|
|
```
|
|
|
|
### Step 3: Update All Controllers
|
|
|
|
Add `[Authorize]` attributes if not already present:
|
|
|
|
```csharp
|
|
[ApiController]
|
|
[Route("api/v1/[controller]")]
|
|
[Authorize] // Ensure JWT authentication
|
|
public class ProjectsController : ControllerBase
|
|
{
|
|
// ... endpoints
|
|
}
|
|
```
|
|
|
|
### Step 4: Update Frontend
|
|
|
|
Update API calls to include tenant context (automatically handled by JWT):
|
|
|
|
```typescript
|
|
// Auth store already handles tenant context via JWT claims
|
|
const { data: projects } = useQuery({
|
|
queryKey: ['projects'],
|
|
queryFn: () => fetch('/api/projects').then(res => res.json()),
|
|
// Tenant filtering handled automatically by backend
|
|
});
|
|
```
|
|
|
|
---
|
|
|
|
## Testing Migration
|
|
|
|
### Test Environment Migration
|
|
|
|
**CRITICAL**: Test the entire migration process in a staging environment first.
|
|
|
|
```bash
|
|
# 1. Clone production database to test environment
|
|
pg_dump -h production-db -U postgres colaflow > colaflow_backup.sql
|
|
psql -h test-db -U postgres -d colaflow_test < colaflow_backup.sql
|
|
|
|
# 2. Run migration scripts on test database
|
|
psql -h test-db -U postgres -d colaflow_test -f migration_scripts/01_create_tenants.sql
|
|
psql -h test-db -U postgres -d colaflow_test -f migration_scripts/02_add_tenant_columns.sql
|
|
# ... run all scripts
|
|
|
|
# 3. Verify data integrity
|
|
psql -h test-db -U postgres -d colaflow_test -f migration_scripts/validate_migration.sql
|
|
|
|
# 4. Deploy updated application code to test environment
|
|
cd colaflow-api
|
|
dotnet publish -c Release
|
|
# Deploy to test server
|
|
|
|
# 5. Run smoke tests
|
|
cd tests
|
|
dotnet test --filter Category=Smoke
|
|
|
|
# 6. Run full test suite
|
|
dotnet test
|
|
|
|
# 7. Manual testing
|
|
# - Login as different tenants
|
|
# - Create/read/update/delete projects
|
|
# - Verify tenant isolation
|
|
```
|
|
|
|
### Data Integrity Validation Script
|
|
|
|
**File**: `migration_scripts/validate_migration.sql`
|
|
|
|
```sql
|
|
-- Validation script for multi-tenancy migration
|
|
|
|
-- 1. Check tenant count
|
|
SELECT COUNT(*) AS tenant_count FROM tenants;
|
|
-- Expected: At least 1 (default tenant)
|
|
|
|
-- 2. Check for NULL tenant_id values
|
|
DO $$
|
|
DECLARE
|
|
table_name TEXT;
|
|
null_count INT;
|
|
BEGIN
|
|
FOR table_name IN
|
|
SELECT tablename FROM pg_tables
|
|
WHERE schemaname = 'public'
|
|
AND tablename NOT IN ('tenants', 'mcp_tokens', 'mcp_audit_logs')
|
|
LOOP
|
|
EXECUTE format('SELECT COUNT(*) FROM %I WHERE tenant_id IS NULL', table_name) INTO null_count;
|
|
IF null_count > 0 THEN
|
|
RAISE WARNING 'Table % has % NULL tenant_id values', table_name, null_count;
|
|
END IF;
|
|
END LOOP;
|
|
END $$;
|
|
-- Expected: No warnings
|
|
|
|
-- 3. Check foreign key integrity
|
|
SELECT
|
|
conrelid::regclass AS table_name,
|
|
conname AS constraint_name,
|
|
pg_get_constraintdef(oid) AS constraint_definition
|
|
FROM pg_constraint
|
|
WHERE contype = 'f' AND conname LIKE '%tenant%';
|
|
-- Expected: All tenant foreign keys present
|
|
|
|
-- 4. Check index existence
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
indexname,
|
|
indexdef
|
|
FROM pg_indexes
|
|
WHERE indexname LIKE '%tenant%'
|
|
ORDER BY tablename, indexname;
|
|
-- Expected: All tenant indexes present
|
|
|
|
-- 5. Verify default tenant has all data
|
|
SELECT
|
|
'users' AS table_name, COUNT(*) AS record_count
|
|
FROM users
|
|
WHERE tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff'
|
|
UNION ALL
|
|
SELECT 'projects', COUNT(*)
|
|
FROM projects
|
|
WHERE tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff'
|
|
UNION ALL
|
|
SELECT 'issues', COUNT(*)
|
|
FROM issues
|
|
WHERE tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff';
|
|
-- Expected: Counts match total records in production
|
|
|
|
-- 6. Check unique constraints
|
|
SELECT
|
|
conrelid::regclass AS table_name,
|
|
conname AS constraint_name,
|
|
pg_get_constraintdef(oid) AS constraint_definition
|
|
FROM pg_constraint
|
|
WHERE contype = 'u' AND pg_get_constraintdef(oid) LIKE '%tenant_id%';
|
|
-- Expected: Tenant-scoped unique constraints present
|
|
|
|
-- 7. Performance check - sample queries with tenant filter
|
|
EXPLAIN ANALYZE
|
|
SELECT * FROM projects WHERE tenant_id = 'ffffffff-ffff-ffff-ffff-ffffffffffff';
|
|
-- Expected: Index scan, not sequential scan
|
|
```
|
|
|
|
---
|
|
|
|
## Deployment Plan
|
|
|
|
### Pre-Deployment
|
|
|
|
1. **Schedule maintenance window** (1-2 hours, off-peak hours)
|
|
2. **Notify all users** 24 hours in advance
|
|
3. **Prepare rollback plan** and test it
|
|
4. **Full database backup**
|
|
5. **Team on standby** (backend, frontend, DevOps)
|
|
|
|
### Deployment Steps
|
|
|
|
#### 1. Maintenance Mode (10 minutes)
|
|
|
|
```bash
|
|
# Enable maintenance mode (return 503 for all requests)
|
|
# Option A: Nginx configuration
|
|
sudo nano /etc/nginx/sites-available/colaflow
|
|
# Add: return 503;
|
|
|
|
# Option B: Application-level maintenance flag
|
|
# Set environment variable: MAINTENANCE_MODE=true
|
|
|
|
# Restart web server
|
|
sudo systemctl reload nginx
|
|
```
|
|
|
|
#### 2. Database Backup (10 minutes)
|
|
|
|
```bash
|
|
# Full backup
|
|
pg_dump -h localhost -U postgres -Fc colaflow > colaflow_backup_$(date +%Y%m%d_%H%M%S).dump
|
|
|
|
# Verify backup
|
|
pg_restore --list colaflow_backup_*.dump | head -20
|
|
|
|
# Copy backup to safe location
|
|
aws s3 cp colaflow_backup_*.dump s3://colaflow-backups/pre-migration/
|
|
```
|
|
|
|
#### 3. Run Database Migration (20-30 minutes)
|
|
|
|
```bash
|
|
# Run migration scripts in order
|
|
cd migration_scripts
|
|
|
|
# 1. Create tenants table
|
|
psql -h localhost -U postgres -d colaflow -f 01_create_tenants.sql
|
|
|
|
# 2. Create default tenant
|
|
psql -h localhost -U postgres -d colaflow -f 02_insert_default_tenant.sql
|
|
|
|
# 3. Add tenant_id columns
|
|
psql -h localhost -U postgres -d colaflow -f 03_add_tenant_columns.sql
|
|
|
|
# 4. Migrate data to default tenant
|
|
psql -h localhost -U postgres -d colaflow -f 04_migrate_data.sql
|
|
|
|
# 5. Validate migration
|
|
psql -h localhost -U postgres -d colaflow -f 05_validate.sql
|
|
|
|
# 6. Set NOT NULL constraints
|
|
psql -h localhost -U postgres -d colaflow -f 06_set_not_null.sql
|
|
|
|
# 7. Create indexes
|
|
psql -h localhost -U postgres -d colaflow -f 07_create_indexes.sql
|
|
|
|
# 8. Update unique constraints
|
|
psql -h localhost -U postgres -d colaflow -f 08_update_constraints.sql
|
|
|
|
# 9. Add SSO columns
|
|
psql -h localhost -U postgres -d colaflow -f 09_add_sso_columns.sql
|
|
|
|
# 10. Create MCP tables
|
|
psql -h localhost -U postgres -d colaflow -f 10_create_mcp_tables.sql
|
|
```
|
|
|
|
#### 4. Deploy Application Code (10 minutes)
|
|
|
|
```bash
|
|
# Backend deployment
|
|
cd colaflow-api
|
|
dotnet publish -c Release -o /var/www/colaflow-api
|
|
|
|
# Restart backend service
|
|
sudo systemctl restart colaflow-api
|
|
|
|
# Verify backend is running
|
|
curl https://api.colaflow.com/health
|
|
|
|
# Frontend deployment
|
|
cd colaflow-web
|
|
npm run build
|
|
rsync -avz --delete out/ /var/www/colaflow-web/
|
|
|
|
# Restart frontend service
|
|
sudo systemctl restart colaflow-web
|
|
```
|
|
|
|
#### 5. Smoke Tests (10 minutes)
|
|
|
|
```bash
|
|
# Run automated smoke tests
|
|
cd tests
|
|
dotnet test --filter Category=Smoke
|
|
|
|
# Manual smoke tests
|
|
# 1. Login as default tenant user
|
|
# 2. View projects list
|
|
# 3. Create new project
|
|
# 4. View issue board
|
|
# 5. Logout and login again
|
|
```
|
|
|
|
#### 6. Disable Maintenance Mode (5 minutes)
|
|
|
|
```bash
|
|
# Remove maintenance flag
|
|
# Nginx: Remove "return 503;" line
|
|
sudo nano /etc/nginx/sites-available/colaflow
|
|
sudo systemctl reload nginx
|
|
|
|
# Or: Set MAINTENANCE_MODE=false
|
|
```
|
|
|
|
#### 7. Monitor (60 minutes)
|
|
|
|
```bash
|
|
# Monitor application logs
|
|
tail -f /var/log/colaflow/api.log
|
|
|
|
# Monitor database performance
|
|
psql -h localhost -U postgres -d colaflow -c "
|
|
SELECT query, calls, total_time, mean_time
|
|
FROM pg_stat_statements
|
|
ORDER BY total_time DESC LIMIT 10;
|
|
"
|
|
|
|
# Monitor error rates
|
|
# Check error tracking service (e.g., Sentry)
|
|
|
|
# Monitor user activity
|
|
# Check analytics dashboard
|
|
```
|
|
|
|
---
|
|
|
|
## Rollback Plan
|
|
|
|
### When to Rollback
|
|
|
|
Rollback if any of these occur:
|
|
- Migration scripts fail
|
|
- Data validation fails
|
|
- Application fails to start
|
|
- Critical functionality broken
|
|
- More than 10% of users report errors
|
|
|
|
### Rollback Steps
|
|
|
|
#### Option 1: Restore from Backup (SAFEST)
|
|
|
|
```bash
|
|
# 1. Stop application
|
|
sudo systemctl stop colaflow-api
|
|
sudo systemctl stop colaflow-web
|
|
|
|
# 2. Drop current database
|
|
psql -h localhost -U postgres -c "DROP DATABASE colaflow;"
|
|
|
|
# 3. Restore from backup
|
|
pg_restore -h localhost -U postgres -Fc -d postgres -C colaflow_backup_*.dump
|
|
|
|
# 4. Deploy previous application version
|
|
cd colaflow-api
|
|
git checkout v1.0.0 # Previous version
|
|
dotnet publish -c Release -o /var/www/colaflow-api
|
|
|
|
cd colaflow-web
|
|
git checkout v1.0.0
|
|
npm run build
|
|
rsync -avz --delete out/ /var/www/colaflow-web/
|
|
|
|
# 5. Restart services
|
|
sudo systemctl start colaflow-api
|
|
sudo systemctl start colaflow-web
|
|
|
|
# 6. Verify rollback
|
|
curl https://api.colaflow.com/health
|
|
```
|
|
|
|
#### Option 2: Reverse Migration (COMPLEX)
|
|
|
|
```sql
|
|
-- WARNING: Only use if Option 1 is not possible
|
|
|
|
-- 1. Drop new tables
|
|
DROP TABLE IF EXISTS mcp_audit_logs CASCADE;
|
|
DROP TABLE IF EXISTS mcp_tokens CASCADE;
|
|
|
|
-- 2. Remove tenant_id columns
|
|
ALTER TABLE users DROP COLUMN IF EXISTS tenant_id CASCADE;
|
|
ALTER TABLE projects DROP COLUMN IF EXISTS tenant_id CASCADE;
|
|
ALTER TABLE issues DROP COLUMN IF EXISTS tenant_id CASCADE;
|
|
-- ... drop from all tables
|
|
|
|
-- 3. Remove SSO columns
|
|
ALTER TABLE users DROP COLUMN IF EXISTS auth_provider;
|
|
ALTER TABLE users DROP COLUMN IF EXISTS external_user_id;
|
|
ALTER TABLE users DROP COLUMN IF EXISTS external_email;
|
|
|
|
-- 4. Restore unique constraints
|
|
ALTER TABLE users DROP CONSTRAINT IF EXISTS uq_users_tenant_email;
|
|
CREATE UNIQUE INDEX ix_users_email ON users(email);
|
|
|
|
-- 5. Drop tenants table
|
|
DROP TABLE IF EXISTS tenants CASCADE;
|
|
|
|
-- 6. Verify rollback
|
|
SELECT COUNT(*) FROM users;
|
|
SELECT COUNT(*) FROM projects;
|
|
```
|
|
|
|
---
|
|
|
|
## Post-Migration Validation
|
|
|
|
### Week 1 Checklist
|
|
|
|
- [ ] **Day 1**: Monitor error rates (< 1%)
|
|
- [ ] **Day 1**: Monitor response times (< 500ms p95)
|
|
- [ ] **Day 1**: User feedback (no critical issues)
|
|
- [ ] **Day 3**: Database performance review
|
|
- [ ] **Day 3**: Slow query analysis
|
|
- [ ] **Day 7**: Full regression testing
|
|
- [ ] **Day 7**: User acceptance sign-off
|
|
|
|
### Performance Monitoring
|
|
|
|
```sql
|
|
-- Slow query analysis
|
|
SELECT
|
|
query,
|
|
calls,
|
|
total_time,
|
|
mean_time,
|
|
stddev_time,
|
|
rows
|
|
FROM pg_stat_statements
|
|
WHERE mean_time > 100 -- Queries taking > 100ms
|
|
ORDER BY total_time DESC
|
|
LIMIT 20;
|
|
|
|
-- Index usage analysis
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
indexname,
|
|
idx_scan AS index_scans,
|
|
idx_tup_read AS tuples_read,
|
|
idx_tup_fetch AS tuples_fetched
|
|
FROM pg_stat_user_indexes
|
|
WHERE schemaname = 'public'
|
|
ORDER BY idx_scan ASC
|
|
LIMIT 20;
|
|
|
|
-- Table bloat check
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) AS total_size,
|
|
pg_size_pretty(pg_relation_size(schemaname||'.'||tablename)) AS table_size,
|
|
pg_size_pretty(pg_indexes_size(schemaname||'.'||tablename)) AS indexes_size
|
|
FROM pg_tables
|
|
WHERE schemaname = 'public'
|
|
ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC
|
|
LIMIT 10;
|
|
```
|
|
|
|
### Data Integrity Checks
|
|
|
|
```sql
|
|
-- Check referential integrity
|
|
SELECT
|
|
COUNT(*) AS orphaned_users
|
|
FROM users u
|
|
LEFT JOIN tenants t ON u.tenant_id = t.id
|
|
WHERE t.id IS NULL;
|
|
-- Expected: 0
|
|
|
|
-- Check tenant isolation
|
|
SELECT
|
|
t.slug AS tenant,
|
|
COUNT(DISTINCT u.id) AS users,
|
|
COUNT(DISTINCT p.id) AS projects,
|
|
COUNT(DISTINCT i.id) AS issues
|
|
FROM tenants t
|
|
LEFT JOIN users u ON u.tenant_id = t.id
|
|
LEFT JOIN projects p ON p.tenant_id = t.id
|
|
LEFT JOIN issues i ON i.tenant_id = t.id
|
|
GROUP BY t.id, t.slug
|
|
ORDER BY t.slug;
|
|
|
|
-- Check for cross-tenant data leaks
|
|
SELECT
|
|
u.email,
|
|
u.tenant_id AS user_tenant,
|
|
p.tenant_id AS project_tenant
|
|
FROM users u
|
|
INNER JOIN projects p ON p.owner_id = u.id
|
|
WHERE u.tenant_id != p.tenant_id;
|
|
-- Expected: 0 rows
|
|
```
|
|
|
|
---
|
|
|
|
## Summary
|
|
|
|
This migration strategy provides:
|
|
|
|
✅ **Zero data loss**: Full backup before migration
|
|
✅ **Minimal downtime**: 30-60 minutes planned maintenance
|
|
✅ **Rollback ready**: Tested rollback procedures
|
|
✅ **Validated approach**: Tested in staging environment
|
|
✅ **Performance optimized**: Composite indexes for tenant queries
|
|
✅ **Security enhanced**: Tenant isolation enforced at database level
|
|
✅ **Production-ready**: Complete scripts and deployment procedures
|
|
|
|
**Next Steps**:
|
|
1. Review and approve this migration strategy
|
|
2. Test migration in staging environment
|
|
3. Schedule maintenance window
|
|
4. Execute migration in production
|
|
5. Monitor and validate for 1 week
|
|
|
|
---
|
|
|
|
**MIGRATION SCRIPTS REPOSITORY**
|
|
|
|
All SQL scripts referenced in this document are available at:
|
|
`c:\Users\yaoji\git\ColaCoder\product-master\migration_scripts\`
|
|
|
|
- `01_create_tenants.sql`
|
|
- `02_insert_default_tenant.sql`
|
|
- `03_add_tenant_columns.sql`
|
|
- `04_migrate_data.sql`
|
|
- `05_validate.sql`
|
|
- `06_set_not_null.sql`
|
|
- `07_create_indexes.sql`
|
|
- `08_update_constraints.sql`
|
|
- `09_add_sso_columns.sql`
|
|
- `10_create_mcp_tables.sql`
|
|
- `99_rollback.sql`
|
|
|
|
**END OF MIGRATION STRATEGY DOCUMENT**
|