154 lines
7.3 KiB
SQL
154 lines
7.3 KiB
SQL
-- Migration: 011_wordpress_import_enhancements
|
|
-- Purpose: Enhance ImportJob and User tables for WordPress CSV import feature
|
|
-- Date: 2025-12-24
|
|
-- Author: Claude Code
|
|
|
|
-- ============================================================================
|
|
-- PART 1: Enhance ImportJob Table
|
|
-- ============================================================================
|
|
|
|
-- Add new columns to import_jobs table for WordPress import tracking
|
|
ALTER TABLE import_jobs
|
|
ADD COLUMN IF NOT EXISTS field_mapping JSONB DEFAULT '{}'::jsonb,
|
|
ADD COLUMN IF NOT EXISTS wordpress_metadata JSONB DEFAULT '{}'::jsonb,
|
|
ADD COLUMN IF NOT EXISTS imported_user_ids JSONB DEFAULT '[]'::jsonb,
|
|
ADD COLUMN IF NOT EXISTS rollback_at TIMESTAMP WITH TIME ZONE,
|
|
ADD COLUMN IF NOT EXISTS rollback_by UUID REFERENCES users(id);
|
|
|
|
-- Add comments for documentation
|
|
COMMENT ON COLUMN import_jobs.field_mapping IS 'Maps CSV columns to database fields: {csv_column: db_field}';
|
|
COMMENT ON COLUMN import_jobs.wordpress_metadata IS 'Stores preview data, validation results, and WordPress-specific metadata';
|
|
COMMENT ON COLUMN import_jobs.imported_user_ids IS 'Array of user IDs created from this import job (for rollback)';
|
|
COMMENT ON COLUMN import_jobs.rollback_at IS 'Timestamp when this import was rolled back';
|
|
COMMENT ON COLUMN import_jobs.rollback_by IS 'Admin user who performed the rollback';
|
|
|
|
-- ============================================================================
|
|
-- PART 2: Add New ImportJob Status Values
|
|
-- ============================================================================
|
|
|
|
-- Add new status values for import workflow
|
|
-- Note: PostgreSQL enum values cannot be added conditionally, so we use DO block
|
|
DO $$
|
|
BEGIN
|
|
-- Add 'validating' status if it doesn't exist
|
|
IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'validating' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'importjobstatus')) THEN
|
|
ALTER TYPE importjobstatus ADD VALUE 'validating';
|
|
END IF;
|
|
|
|
-- Add 'preview_ready' status if it doesn't exist
|
|
IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'preview_ready' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'importjobstatus')) THEN
|
|
ALTER TYPE importjobstatus ADD VALUE 'preview_ready';
|
|
END IF;
|
|
|
|
-- Add 'rolled_back' status if it doesn't exist
|
|
IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'rolled_back' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'importjobstatus')) THEN
|
|
ALTER TYPE importjobstatus ADD VALUE 'rolled_back';
|
|
END IF;
|
|
END$$;
|
|
|
|
-- ============================================================================
|
|
-- PART 3: Enhance User Table for Import Tracking
|
|
-- ============================================================================
|
|
|
|
-- Add columns to track import source and WordPress metadata
|
|
ALTER TABLE users
|
|
ADD COLUMN IF NOT EXISTS import_source VARCHAR(50),
|
|
ADD COLUMN IF NOT EXISTS import_job_id UUID REFERENCES import_jobs(id),
|
|
ADD COLUMN IF NOT EXISTS wordpress_user_id BIGINT,
|
|
ADD COLUMN IF NOT EXISTS wordpress_registered_date TIMESTAMP WITH TIME ZONE;
|
|
|
|
-- Add comments for documentation
|
|
COMMENT ON COLUMN users.import_source IS 'Source of user creation: wordpress, manual, registration, etc.';
|
|
COMMENT ON COLUMN users.import_job_id IS 'Reference to import job that created this user (if imported)';
|
|
COMMENT ON COLUMN users.wordpress_user_id IS 'Original WordPress user ID for reference';
|
|
COMMENT ON COLUMN users.wordpress_registered_date IS 'Original WordPress registration date';
|
|
|
|
-- ============================================================================
|
|
-- PART 4: Create Indexes for Performance
|
|
-- ============================================================================
|
|
|
|
-- Index for querying users by import job (used in rollback)
|
|
CREATE INDEX IF NOT EXISTS idx_users_import_job
|
|
ON users(import_job_id)
|
|
WHERE import_job_id IS NOT NULL;
|
|
|
|
-- Index for querying users by import source
|
|
CREATE INDEX IF NOT EXISTS idx_users_import_source
|
|
ON users(import_source)
|
|
WHERE import_source IS NOT NULL;
|
|
|
|
-- Index for querying import jobs by status
|
|
CREATE INDEX IF NOT EXISTS idx_import_jobs_status
|
|
ON import_jobs(status);
|
|
|
|
-- ============================================================================
|
|
-- PART 5: Create Rollback Audit Table (Optional but Recommended)
|
|
-- ============================================================================
|
|
|
|
-- Create table to track import rollback history for audit purposes
|
|
CREATE TABLE IF NOT EXISTS import_rollback_audit (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
import_job_id UUID NOT NULL REFERENCES import_jobs(id),
|
|
rolled_back_by UUID NOT NULL REFERENCES users(id),
|
|
rolled_back_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
deleted_user_count INTEGER NOT NULL,
|
|
deleted_user_ids JSONB NOT NULL,
|
|
reason TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Index for querying rollback history
|
|
CREATE INDEX IF NOT EXISTS idx_rollback_audit_import_job
|
|
ON import_rollback_audit(import_job_id);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_rollback_audit_rolled_back_at
|
|
ON import_rollback_audit(rolled_back_at DESC);
|
|
|
|
COMMENT ON TABLE import_rollback_audit IS 'Audit trail for import rollback operations';
|
|
|
|
-- ============================================================================
|
|
-- VERIFICATION QUERIES (Run after migration to verify)
|
|
-- ============================================================================
|
|
|
|
-- Verify ImportJob columns exist
|
|
-- SELECT column_name, data_type
|
|
-- FROM information_schema.columns
|
|
-- WHERE table_name = 'import_jobs'
|
|
-- AND column_name IN ('field_mapping', 'wordpress_metadata', 'imported_user_ids', 'rollback_at', 'rollback_by');
|
|
|
|
-- Verify User columns exist
|
|
-- SELECT column_name, data_type
|
|
-- FROM information_schema.columns
|
|
-- WHERE table_name = 'users'
|
|
-- AND column_name IN ('import_source', 'import_job_id', 'wordpress_user_id', 'wordpress_registered_date');
|
|
|
|
-- Verify new enum values exist
|
|
-- SELECT enumlabel FROM pg_enum WHERE enumtypid = (SELECT oid FROM pg_type WHERE typname = 'importjobstatus') ORDER BY enumlabel;
|
|
|
|
-- Verify indexes exist
|
|
-- SELECT indexname, indexdef FROM pg_indexes WHERE tablename IN ('users', 'import_jobs', 'import_rollback_audit') ORDER BY indexname;
|
|
|
|
-- ============================================================================
|
|
-- ROLLBACK SCRIPT (if needed)
|
|
-- ============================================================================
|
|
|
|
-- WARNING: This will drop all columns and data related to WordPress imports
|
|
-- USE WITH EXTREME CAUTION
|
|
|
|
-- DROP TABLE IF EXISTS import_rollback_audit CASCADE;
|
|
-- DROP INDEX IF EXISTS idx_users_import_job;
|
|
-- DROP INDEX IF EXISTS idx_users_import_source;
|
|
-- DROP INDEX IF EXISTS idx_import_jobs_status;
|
|
-- ALTER TABLE users DROP COLUMN IF EXISTS import_source;
|
|
-- ALTER TABLE users DROP COLUMN IF EXISTS import_job_id;
|
|
-- ALTER TABLE users DROP COLUMN IF EXISTS wordpress_user_id;
|
|
-- ALTER TABLE users DROP COLUMN IF EXISTS wordpress_registered_date;
|
|
-- ALTER TABLE import_jobs DROP COLUMN IF EXISTS field_mapping;
|
|
-- ALTER TABLE import_jobs DROP COLUMN IF EXISTS wordpress_metadata;
|
|
-- ALTER TABLE import_jobs DROP COLUMN IF EXISTS imported_user_ids;
|
|
-- ALTER TABLE import_jobs DROP COLUMN IF EXISTS rollback_at;
|
|
-- ALTER TABLE import_jobs DROP COLUMN IF EXISTS rollback_by;
|
|
|
|
-- Note: Cannot easily remove enum values from importjobstatus type without recreating it
|
|
-- Manual intervention required if rollback of enum values is needed
|