SECURITY CLEANUP COMPLETED High Priority - Sensitive Data Removed: - Delete directus_ecosystem_with_keys.js (contained DB password & API keys) - Delete directus_ecosystem_updated.js (contained credentials) - Delete directus_ecosystem_final.js (CRITICAL: real OpenAI API key) - Delete temp_server.env (complete production secrets) - Delete check_config.js (API key inspection script) - Delete extract_keys.ps1/.bat (key extraction scripts) - Delete fix_database_url.sh (server IP & SSH paths) - Delete setup_fcm_server.sh (sensitive config procedures) Medium Priority - AI-Generated Test Files: - Delete 5 test JavaScript files (OpenAI, Go backend, Vision API tests) - Delete 10 test registration JSON files (registration flow tests) - Delete 4 temporary Go files (AI-generated patches) Low Priority - Temporary Artifacts: - Delete _tmp_* files and directories - Delete log files (api_logs.txt, web_errors.log, flutter_01.log, log.ini) - Delete import requests.py (Python test script) Files Secured (Legitimate): - Keep .env file (contains legitimate production secrets) - Keep production scripts and configuration files - Keep organized migrations and documentation Cleanup Summary: - 30+ files removed - Risk level: HIGH LOW - No exposed API keys or credentials - Clean project structure - Enhanced security posture Documentation Added: - SECURITY_AUDIT_CLEANUP.md - Complete audit report - SQL_MIGRATION_ORGANIZATION.md - Migration organization guide - ENHANCED_REGISTRATION_FLOW.md - Registration system docs - TURNSTILE_INTEGRATION_COMPLETE.md - Security integration docs - USER_APPEAL_SYSTEM.md - Appeal system documentation Benefits: - Eliminated API key exposure - Removed sensitive server information - Clean AI-generated test artifacts - Professional project organization - Enhanced security practices - Comprehensive documentation
106 lines
4.8 KiB
PL/PgSQL
106 lines
4.8 KiB
PL/PgSQL
-- Create moderation_flags table for AI-powered content moderation
|
|
CREATE TABLE IF NOT EXISTS moderation_flags (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
post_id UUID REFERENCES posts(id) ON DELETE CASCADE,
|
|
comment_id UUID REFERENCES comments(id) ON DELETE CASCADE,
|
|
flag_reason TEXT NOT NULL,
|
|
scores JSONB NOT NULL,
|
|
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'rejected', 'escalated')),
|
|
reviewed_by UUID REFERENCES users(id),
|
|
reviewed_at TIMESTAMP WITH TIME ZONE,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
|
|
-- Ensure at least one of post_id or comment_id is set
|
|
CONSTRAINT moderation_flags_content_check CHECK (
|
|
(post_id IS NOT NULL) OR (comment_id IS NOT NULL)
|
|
)
|
|
);
|
|
|
|
-- Add indexes for performance
|
|
CREATE INDEX IF NOT EXISTS idx_moderation_flags_post_id ON moderation_flags(post_id);
|
|
CREATE INDEX IF NOT EXISTS idx_moderation_flags_comment_id ON moderation_flags(comment_id);
|
|
CREATE INDEX IF NOT EXISTS idx_moderation_flags_status ON moderation_flags(status);
|
|
CREATE INDEX IF NOT EXISTS idx_moderation_flags_created_at ON moderation_flags(created_at);
|
|
|
|
-- Add GIN index for JSONB scores to enable efficient querying
|
|
CREATE INDEX IF NOT EXISTS idx_moderation_flags_scores_gin ON moderation_flags USING GIN(scores);
|
|
|
|
-- Add status column to users table for user moderation
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS status TEXT DEFAULT 'active' CHECK (status IN ('active', 'suspended', 'banned'));
|
|
|
|
-- Add index for user status queries
|
|
CREATE INDEX IF NOT EXISTS idx_users_status ON users(status);
|
|
|
|
-- Create user_status_history table to track status changes
|
|
CREATE TABLE IF NOT EXISTS user_status_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
old_status TEXT,
|
|
new_status TEXT NOT NULL,
|
|
reason TEXT,
|
|
changed_by UUID REFERENCES users(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Add index for user status history queries
|
|
CREATE INDEX IF NOT EXISTS idx_user_status_history_user_id ON user_status_history(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_status_history_created_at ON user_status_history(created_at);
|
|
|
|
-- Create trigger to update updated_at timestamp
|
|
CREATE OR REPLACE FUNCTION update_moderation_flags_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER moderation_flags_updated_at
|
|
BEFORE UPDATE ON moderation_flags
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_moderation_flags_updated_at();
|
|
|
|
-- Create trigger to track user status changes
|
|
CREATE OR REPLACE FUNCTION log_user_status_change()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF OLD.status IS DISTINCT FROM NEW.status THEN
|
|
INSERT INTO user_status_history (user_id, old_status, new_status, changed_by)
|
|
VALUES (NEW.id, OLD.status, NEW.status, NEW.id);
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER user_status_change_log
|
|
BEFORE UPDATE ON users
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION log_user_status_change();
|
|
|
|
-- Grant permissions to Directus
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON moderation_flags TO directus;
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON user_status_history TO directus;
|
|
GRANT SELECT, UPDATE ON users TO directus;
|
|
GRANT USAGE ON ALL SEQUENCES IN SCHEMA public TO directus;
|
|
|
|
-- Add comments for Directus UI
|
|
COMMENT ON TABLE moderation_flags IS 'AI-powered content moderation flags for posts and comments';
|
|
COMMENT ON COLUMN moderation_flags.id IS 'Unique identifier for the moderation flag';
|
|
COMMENT ON COLUMN moderation_flags.post_id IS 'Reference to the post being moderated';
|
|
COMMENT ON COLUMN moderation_flags.comment_id IS 'Reference to the comment being moderated';
|
|
COMMENT ON COLUMN moderation_flags.flag_reason IS 'Primary reason for flag (hate, greed, delusion, etc.)';
|
|
COMMENT ON COLUMN moderation_flags.scores IS 'JSON object containing detailed analysis scores';
|
|
COMMENT ON COLUMN moderation_flags.status IS 'Current moderation status (pending, approved, rejected, escalated)';
|
|
COMMENT ON COLUMN moderation_flags.reviewed_by IS 'Admin who reviewed this flag';
|
|
COMMENT ON COLUMN moderation_flags.reviewed_at IS 'When this flag was reviewed';
|
|
|
|
COMMENT ON TABLE user_status_history IS 'History of user status changes for audit trail';
|
|
COMMENT ON COLUMN user_status_history.user_id IS 'User whose status changed';
|
|
COMMENT ON COLUMN user_status_history.old_status IS 'Previous status before change';
|
|
COMMENT ON COLUMN user_status_history.new_status IS 'New status after change';
|
|
COMMENT ON COLUMN user_status_history.reason IS 'Reason for status change';
|
|
COMMENT ON COLUMN user_status_history.changed_by IS 'Admin who made the change';
|
|
|
|
COMMENT ON COLUMN users.status IS 'Current user moderation status (active, suspended, banned)';
|