94 lines
3.6 KiB
SQL
94 lines
3.6 KiB
SQL
-- Admin Panel Support Tables
|
|
|
|
-- Algorithm configuration (key-value store for feed/moderation tuning)
|
|
CREATE TABLE IF NOT EXISTS public.algorithm_config (
|
|
key TEXT PRIMARY KEY,
|
|
value TEXT NOT NULL,
|
|
description TEXT,
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Seed default algorithm config values
|
|
INSERT INTO public.algorithm_config (key, value, description) VALUES
|
|
('feed_recency_weight', '0.4', 'Weight for post recency in feed ranking'),
|
|
('feed_engagement_weight', '0.3', 'Weight for engagement metrics (likes, comments)'),
|
|
('feed_harmony_weight', '0.2', 'Weight for author harmony/trust score'),
|
|
('feed_diversity_weight', '0.1', 'Weight for content diversity in feed'),
|
|
('moderation_auto_flag_threshold', '0.7', 'AI score threshold for auto-flagging content'),
|
|
('moderation_auto_remove_threshold', '0.95', 'AI score threshold for automatic content removal'),
|
|
('moderation_greed_keyword_threshold', '0.7', 'Keyword-based spam/greed detection threshold'),
|
|
('feed_max_posts_per_author', '3', 'Max posts from same author in a single feed page'),
|
|
('feed_boost_mutual_follow', '1.5', 'Multiplier boost for posts from mutual follows'),
|
|
('feed_beacon_boost', '1.2', 'Multiplier boost for beacon posts in nearby feeds')
|
|
ON CONFLICT (key) DO NOTHING;
|
|
|
|
-- Audit log for admin actions
|
|
CREATE TABLE IF NOT EXISTS public.audit_log (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
actor_id UUID REFERENCES public.profiles(id) ON DELETE SET NULL,
|
|
action TEXT NOT NULL,
|
|
target_type TEXT NOT NULL, -- 'user', 'post', 'comment', 'appeal', 'report', 'config'
|
|
target_id UUID,
|
|
details TEXT, -- JSON string with action-specific details
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_created_at ON public.audit_log(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_actor_id ON public.audit_log(actor_id);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_action ON public.audit_log(action);
|
|
|
|
-- Ensure profiles.role column exists (may already exist from prior migrations)
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public' AND table_name = 'profiles' AND column_name = 'role'
|
|
) THEN
|
|
ALTER TABLE public.profiles ADD COLUMN role TEXT NOT NULL DEFAULT 'user';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Ensure profiles.is_verified column exists
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public' AND table_name = 'profiles' AND column_name = 'is_verified'
|
|
) THEN
|
|
ALTER TABLE public.profiles ADD COLUMN is_verified BOOLEAN DEFAULT FALSE;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Ensure profiles.is_private column exists
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public' AND table_name = 'profiles' AND column_name = 'is_private'
|
|
) THEN
|
|
ALTER TABLE public.profiles ADD COLUMN is_private BOOLEAN DEFAULT FALSE;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Ensure users.status column exists
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public' AND table_name = 'users' AND column_name = 'status'
|
|
) THEN
|
|
ALTER TABLE public.users ADD COLUMN status TEXT NOT NULL DEFAULT 'active';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Ensure users.last_login column exists
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public' AND table_name = 'users' AND column_name = 'last_login'
|
|
) THEN
|
|
ALTER TABLE public.users ADD COLUMN last_login TIMESTAMPTZ;
|
|
END IF;
|
|
END $$;
|