mirror of
https://codeberg.org/likwid/likwid.git
synced 2026-02-09 21:13:09 +00:00
555 lines
18 KiB
MySQL
555 lines
18 KiB
MySQL
|
|
-- Moderation Ledger Plugin
|
||
|
|
-- Immutable, cryptographically-chained log of all moderation decisions
|
||
|
|
-- This plugin is NON-DEACTIVATABLE by design (core transparency requirement)
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- CORE LEDGER TABLE
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Moderation action types
|
||
|
|
CREATE TYPE moderation_action_type AS ENUM (
|
||
|
|
-- Content moderation
|
||
|
|
'content_remove',
|
||
|
|
'content_hide',
|
||
|
|
'content_restore',
|
||
|
|
'content_edit',
|
||
|
|
'content_flag',
|
||
|
|
'content_unflag',
|
||
|
|
|
||
|
|
-- User moderation
|
||
|
|
'user_warn',
|
||
|
|
'user_mute',
|
||
|
|
'user_unmute',
|
||
|
|
'user_suspend',
|
||
|
|
'user_unsuspend',
|
||
|
|
'user_ban',
|
||
|
|
'user_unban',
|
||
|
|
'user_role_change',
|
||
|
|
|
||
|
|
-- Community moderation
|
||
|
|
'community_setting_change',
|
||
|
|
'community_rule_add',
|
||
|
|
'community_rule_edit',
|
||
|
|
'community_rule_remove',
|
||
|
|
|
||
|
|
-- Proposal/voting moderation
|
||
|
|
'proposal_close',
|
||
|
|
'proposal_reopen',
|
||
|
|
'proposal_archive',
|
||
|
|
'vote_invalidate',
|
||
|
|
'vote_restore',
|
||
|
|
|
||
|
|
-- Escalation
|
||
|
|
'escalate_to_admin',
|
||
|
|
'escalate_to_community',
|
||
|
|
'appeal_received',
|
||
|
|
'appeal_resolved'
|
||
|
|
);
|
||
|
|
|
||
|
|
-- The immutable ledger entries
|
||
|
|
CREATE TABLE moderation_ledger (
|
||
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
|
|
|
||
|
|
-- Sequence for ordering (monotonically increasing per community)
|
||
|
|
sequence_number BIGINT NOT NULL,
|
||
|
|
|
||
|
|
-- Context
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE SET NULL,
|
||
|
|
|
||
|
|
-- Who took the action
|
||
|
|
actor_user_id UUID NOT NULL REFERENCES users(id),
|
||
|
|
actor_role TEXT NOT NULL, -- Role at time of action (preserved for history)
|
||
|
|
|
||
|
|
-- What action was taken
|
||
|
|
action_type moderation_action_type NOT NULL,
|
||
|
|
|
||
|
|
-- Target of the action
|
||
|
|
target_type TEXT NOT NULL, -- 'user', 'proposal', 'comment', 'community', etc.
|
||
|
|
target_id UUID NOT NULL,
|
||
|
|
target_snapshot JSONB, -- Snapshot of target state before action (for context)
|
||
|
|
|
||
|
|
-- Decision details
|
||
|
|
reason TEXT NOT NULL, -- Required justification
|
||
|
|
rule_reference TEXT, -- Which community rule was violated (if applicable)
|
||
|
|
evidence JSONB, -- Links, screenshots (hashed references), reports
|
||
|
|
|
||
|
|
-- Duration (for temporary actions)
|
||
|
|
duration_hours INTEGER, -- NULL = permanent
|
||
|
|
expires_at TIMESTAMPTZ,
|
||
|
|
|
||
|
|
-- Voting context (for community-voted decisions)
|
||
|
|
decision_type TEXT NOT NULL DEFAULT 'unilateral', -- 'unilateral', 'voted', 'automated'
|
||
|
|
vote_proposal_id UUID REFERENCES proposals(id),
|
||
|
|
vote_result JSONB, -- Summary of vote if applicable
|
||
|
|
|
||
|
|
-- Cryptographic chain
|
||
|
|
previous_hash TEXT NOT NULL, -- SHA-256 of previous entry (or genesis hash)
|
||
|
|
entry_hash TEXT NOT NULL, -- SHA-256 of this entry's content
|
||
|
|
|
||
|
|
-- Timestamps
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
|
||
|
|
-- Prevent modifications
|
||
|
|
CONSTRAINT ledger_immutable CHECK (true) -- Symbolic; real protection via triggers
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Unique sequence per community
|
||
|
|
CREATE UNIQUE INDEX idx_ledger_community_sequence
|
||
|
|
ON moderation_ledger(community_id, sequence_number);
|
||
|
|
|
||
|
|
-- Fast lookups
|
||
|
|
CREATE INDEX idx_ledger_actor ON moderation_ledger(actor_user_id);
|
||
|
|
CREATE INDEX idx_ledger_target ON moderation_ledger(target_type, target_id);
|
||
|
|
CREATE INDEX idx_ledger_action ON moderation_ledger(action_type);
|
||
|
|
CREATE INDEX idx_ledger_created ON moderation_ledger(created_at);
|
||
|
|
CREATE INDEX idx_ledger_community ON moderation_ledger(community_id);
|
||
|
|
|
||
|
|
-- Hash chain verification index
|
||
|
|
CREATE INDEX idx_ledger_hash_chain ON moderation_ledger(community_id, previous_hash);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- GENESIS ENTRIES (one per community + one global)
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE ledger_genesis (
|
||
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
|
|
community_id UUID UNIQUE REFERENCES communities(id) ON DELETE CASCADE,
|
||
|
|
genesis_hash TEXT NOT NULL,
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Global genesis (community_id = NULL)
|
||
|
|
INSERT INTO ledger_genesis (community_id, genesis_hash)
|
||
|
|
VALUES (NULL, 'GENESIS:' || encode(sha256('LIKWID_MODERATION_LEDGER_GENESIS_v1'::bytea), 'hex'));
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- IMMUTABILITY PROTECTION
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Prevent UPDATE on ledger entries
|
||
|
|
CREATE OR REPLACE FUNCTION ledger_prevent_update()
|
||
|
|
RETURNS TRIGGER AS $$
|
||
|
|
BEGIN
|
||
|
|
RAISE EXCEPTION 'Moderation ledger entries are immutable and cannot be modified';
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE TRIGGER trg_ledger_no_update
|
||
|
|
BEFORE UPDATE ON moderation_ledger
|
||
|
|
FOR EACH ROW
|
||
|
|
EXECUTE FUNCTION ledger_prevent_update();
|
||
|
|
|
||
|
|
-- Prevent DELETE on ledger entries (except by superuser for GDPR compliance)
|
||
|
|
CREATE OR REPLACE FUNCTION ledger_prevent_delete()
|
||
|
|
RETURNS TRIGGER AS $$
|
||
|
|
BEGIN
|
||
|
|
-- Allow deletion only by superuser (for legal compliance like GDPR)
|
||
|
|
IF NOT current_setting('likwid.allow_ledger_delete', true)::boolean THEN
|
||
|
|
RAISE EXCEPTION 'Moderation ledger entries cannot be deleted. Set likwid.allow_ledger_delete = true for legal compliance deletions.';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Log the deletion attempt
|
||
|
|
INSERT INTO ledger_deletion_log (entry_id, deleted_by, reason)
|
||
|
|
VALUES (OLD.id, current_user, current_setting('likwid.deletion_reason', true));
|
||
|
|
|
||
|
|
RETURN OLD;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE TRIGGER trg_ledger_no_delete
|
||
|
|
BEFORE DELETE ON moderation_ledger
|
||
|
|
FOR EACH ROW
|
||
|
|
EXECUTE FUNCTION ledger_prevent_delete();
|
||
|
|
|
||
|
|
-- Log of any forced deletions (for GDPR compliance auditing)
|
||
|
|
CREATE TABLE ledger_deletion_log (
|
||
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
|
|
entry_id UUID NOT NULL, -- ID of deleted entry (no FK since it's deleted)
|
||
|
|
deleted_by TEXT NOT NULL,
|
||
|
|
reason TEXT,
|
||
|
|
deleted_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||
|
|
);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- HELPER FUNCTIONS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Get the genesis hash for a community (or global)
|
||
|
|
CREATE OR REPLACE FUNCTION get_ledger_genesis_hash(p_community_id UUID)
|
||
|
|
RETURNS TEXT AS $$
|
||
|
|
DECLARE
|
||
|
|
v_hash TEXT;
|
||
|
|
BEGIN
|
||
|
|
SELECT genesis_hash INTO v_hash
|
||
|
|
FROM ledger_genesis
|
||
|
|
WHERE community_id IS NOT DISTINCT FROM p_community_id;
|
||
|
|
|
||
|
|
IF v_hash IS NULL THEN
|
||
|
|
-- Create genesis for this community
|
||
|
|
v_hash := 'GENESIS:' || encode(sha256(('LIKWID_COMMUNITY_' || COALESCE(p_community_id::text, 'GLOBAL'))::bytea), 'hex');
|
||
|
|
INSERT INTO ledger_genesis (community_id, genesis_hash) VALUES (p_community_id, v_hash);
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
RETURN v_hash;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Get the last entry hash for a community
|
||
|
|
CREATE OR REPLACE FUNCTION get_last_ledger_hash(p_community_id UUID)
|
||
|
|
RETURNS TEXT AS $$
|
||
|
|
DECLARE
|
||
|
|
v_hash TEXT;
|
||
|
|
BEGIN
|
||
|
|
SELECT entry_hash INTO v_hash
|
||
|
|
FROM moderation_ledger
|
||
|
|
WHERE community_id IS NOT DISTINCT FROM p_community_id
|
||
|
|
ORDER BY sequence_number DESC
|
||
|
|
LIMIT 1;
|
||
|
|
|
||
|
|
IF v_hash IS NULL THEN
|
||
|
|
RETURN get_ledger_genesis_hash(p_community_id);
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
RETURN v_hash;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Get next sequence number for a community
|
||
|
|
CREATE OR REPLACE FUNCTION get_next_ledger_sequence(p_community_id UUID)
|
||
|
|
RETURNS BIGINT AS $$
|
||
|
|
DECLARE
|
||
|
|
v_seq BIGINT;
|
||
|
|
BEGIN
|
||
|
|
SELECT COALESCE(MAX(sequence_number), 0) + 1 INTO v_seq
|
||
|
|
FROM moderation_ledger
|
||
|
|
WHERE community_id IS NOT DISTINCT FROM p_community_id;
|
||
|
|
|
||
|
|
RETURN v_seq;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Calculate entry hash (deterministic)
|
||
|
|
CREATE OR REPLACE FUNCTION calculate_ledger_entry_hash(
|
||
|
|
p_sequence BIGINT,
|
||
|
|
p_community_id UUID,
|
||
|
|
p_actor_user_id UUID,
|
||
|
|
p_action_type moderation_action_type,
|
||
|
|
p_target_type TEXT,
|
||
|
|
p_target_id UUID,
|
||
|
|
p_reason TEXT,
|
||
|
|
p_previous_hash TEXT,
|
||
|
|
p_created_at TIMESTAMPTZ
|
||
|
|
)
|
||
|
|
RETURNS TEXT AS $$
|
||
|
|
DECLARE
|
||
|
|
v_content TEXT;
|
||
|
|
BEGIN
|
||
|
|
-- Create deterministic content string
|
||
|
|
v_content :=
|
||
|
|
p_sequence::text || '|' ||
|
||
|
|
COALESCE(p_community_id::text, 'NULL') || '|' ||
|
||
|
|
p_actor_user_id::text || '|' ||
|
||
|
|
p_action_type::text || '|' ||
|
||
|
|
p_target_type || '|' ||
|
||
|
|
p_target_id::text || '|' ||
|
||
|
|
p_reason || '|' ||
|
||
|
|
p_previous_hash || '|' ||
|
||
|
|
p_created_at::text;
|
||
|
|
|
||
|
|
RETURN encode(sha256(v_content::bytea), 'hex');
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql IMMUTABLE;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- ENTRY CREATION (with automatic hashing)
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION create_ledger_entry(
|
||
|
|
p_community_id UUID,
|
||
|
|
p_actor_user_id UUID,
|
||
|
|
p_actor_role TEXT,
|
||
|
|
p_action_type moderation_action_type,
|
||
|
|
p_target_type TEXT,
|
||
|
|
p_target_id UUID,
|
||
|
|
p_reason TEXT,
|
||
|
|
p_rule_reference TEXT DEFAULT NULL,
|
||
|
|
p_evidence JSONB DEFAULT NULL,
|
||
|
|
p_target_snapshot JSONB DEFAULT NULL,
|
||
|
|
p_duration_hours INTEGER DEFAULT NULL,
|
||
|
|
p_decision_type TEXT DEFAULT 'unilateral',
|
||
|
|
p_vote_proposal_id UUID DEFAULT NULL,
|
||
|
|
p_vote_result JSONB DEFAULT NULL
|
||
|
|
)
|
||
|
|
RETURNS UUID AS $$
|
||
|
|
DECLARE
|
||
|
|
v_entry_id UUID;
|
||
|
|
v_sequence BIGINT;
|
||
|
|
v_previous_hash TEXT;
|
||
|
|
v_entry_hash TEXT;
|
||
|
|
v_created_at TIMESTAMPTZ;
|
||
|
|
v_expires_at TIMESTAMPTZ;
|
||
|
|
BEGIN
|
||
|
|
-- Lock to prevent race conditions
|
||
|
|
PERFORM pg_advisory_xact_lock(hashtext('ledger_' || COALESCE(p_community_id::text, 'global')));
|
||
|
|
|
||
|
|
v_created_at := NOW();
|
||
|
|
v_sequence := get_next_ledger_sequence(p_community_id);
|
||
|
|
v_previous_hash := get_last_ledger_hash(p_community_id);
|
||
|
|
|
||
|
|
-- Calculate expiry if duration specified
|
||
|
|
IF p_duration_hours IS NOT NULL THEN
|
||
|
|
v_expires_at := v_created_at + (p_duration_hours || ' hours')::interval;
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Calculate entry hash
|
||
|
|
v_entry_hash := calculate_ledger_entry_hash(
|
||
|
|
v_sequence,
|
||
|
|
p_community_id,
|
||
|
|
p_actor_user_id,
|
||
|
|
p_action_type,
|
||
|
|
p_target_type,
|
||
|
|
p_target_id,
|
||
|
|
p_reason,
|
||
|
|
v_previous_hash,
|
||
|
|
v_created_at
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Insert the entry
|
||
|
|
INSERT INTO moderation_ledger (
|
||
|
|
sequence_number,
|
||
|
|
community_id,
|
||
|
|
actor_user_id,
|
||
|
|
actor_role,
|
||
|
|
action_type,
|
||
|
|
target_type,
|
||
|
|
target_id,
|
||
|
|
target_snapshot,
|
||
|
|
reason,
|
||
|
|
rule_reference,
|
||
|
|
evidence,
|
||
|
|
duration_hours,
|
||
|
|
expires_at,
|
||
|
|
decision_type,
|
||
|
|
vote_proposal_id,
|
||
|
|
vote_result,
|
||
|
|
previous_hash,
|
||
|
|
entry_hash,
|
||
|
|
created_at
|
||
|
|
) VALUES (
|
||
|
|
v_sequence,
|
||
|
|
p_community_id,
|
||
|
|
p_actor_user_id,
|
||
|
|
p_actor_role,
|
||
|
|
p_action_type,
|
||
|
|
p_target_type,
|
||
|
|
p_target_id,
|
||
|
|
p_target_snapshot,
|
||
|
|
p_reason,
|
||
|
|
p_rule_reference,
|
||
|
|
p_evidence,
|
||
|
|
p_duration_hours,
|
||
|
|
v_expires_at,
|
||
|
|
p_decision_type,
|
||
|
|
p_vote_proposal_id,
|
||
|
|
p_vote_result,
|
||
|
|
v_previous_hash,
|
||
|
|
v_entry_hash,
|
||
|
|
v_created_at
|
||
|
|
)
|
||
|
|
RETURNING id INTO v_entry_id;
|
||
|
|
|
||
|
|
RETURN v_entry_id;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- CHAIN VERIFICATION
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Verify the integrity of the ledger chain for a community
|
||
|
|
CREATE OR REPLACE FUNCTION verify_ledger_chain(p_community_id UUID)
|
||
|
|
RETURNS TABLE (
|
||
|
|
is_valid BOOLEAN,
|
||
|
|
total_entries BIGINT,
|
||
|
|
broken_at_sequence BIGINT,
|
||
|
|
expected_hash TEXT,
|
||
|
|
actual_hash TEXT,
|
||
|
|
error_message TEXT
|
||
|
|
) AS $$
|
||
|
|
DECLARE
|
||
|
|
v_entry RECORD;
|
||
|
|
v_expected_hash TEXT;
|
||
|
|
v_calculated_hash TEXT;
|
||
|
|
v_count BIGINT := 0;
|
||
|
|
BEGIN
|
||
|
|
-- Get genesis hash
|
||
|
|
v_expected_hash := get_ledger_genesis_hash(p_community_id);
|
||
|
|
|
||
|
|
-- Iterate through all entries in order
|
||
|
|
FOR v_entry IN
|
||
|
|
SELECT * FROM moderation_ledger
|
||
|
|
WHERE community_id IS NOT DISTINCT FROM p_community_id
|
||
|
|
ORDER BY sequence_number ASC
|
||
|
|
LOOP
|
||
|
|
v_count := v_count + 1;
|
||
|
|
|
||
|
|
-- Check previous hash matches expected
|
||
|
|
IF v_entry.previous_hash != v_expected_hash THEN
|
||
|
|
RETURN QUERY SELECT
|
||
|
|
false,
|
||
|
|
v_count,
|
||
|
|
v_entry.sequence_number,
|
||
|
|
v_expected_hash,
|
||
|
|
v_entry.previous_hash,
|
||
|
|
'Previous hash mismatch at sequence ' || v_entry.sequence_number;
|
||
|
|
RETURN;
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Recalculate entry hash
|
||
|
|
v_calculated_hash := calculate_ledger_entry_hash(
|
||
|
|
v_entry.sequence_number,
|
||
|
|
v_entry.community_id,
|
||
|
|
v_entry.actor_user_id,
|
||
|
|
v_entry.action_type,
|
||
|
|
v_entry.target_type,
|
||
|
|
v_entry.target_id,
|
||
|
|
v_entry.reason,
|
||
|
|
v_entry.previous_hash,
|
||
|
|
v_entry.created_at
|
||
|
|
);
|
||
|
|
|
||
|
|
IF v_calculated_hash != v_entry.entry_hash THEN
|
||
|
|
RETURN QUERY SELECT
|
||
|
|
false,
|
||
|
|
v_count,
|
||
|
|
v_entry.sequence_number,
|
||
|
|
v_calculated_hash,
|
||
|
|
v_entry.entry_hash,
|
||
|
|
'Entry hash mismatch at sequence ' || v_entry.sequence_number;
|
||
|
|
RETURN;
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Next iteration expects this entry's hash
|
||
|
|
v_expected_hash := v_entry.entry_hash;
|
||
|
|
END LOOP;
|
||
|
|
|
||
|
|
-- All good
|
||
|
|
RETURN QUERY SELECT true, v_count, NULL::BIGINT, NULL::TEXT, NULL::TEXT, NULL::TEXT;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- VIEWS FOR EASIER QUERYING
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Human-readable ledger view
|
||
|
|
CREATE OR REPLACE VIEW v_moderation_ledger AS
|
||
|
|
SELECT
|
||
|
|
ml.id,
|
||
|
|
ml.sequence_number,
|
||
|
|
ml.community_id,
|
||
|
|
c.name AS community_name,
|
||
|
|
ml.actor_user_id,
|
||
|
|
u.username AS actor_username,
|
||
|
|
u.display_name AS actor_display_name,
|
||
|
|
ml.actor_role,
|
||
|
|
ml.action_type,
|
||
|
|
ml.target_type,
|
||
|
|
ml.target_id,
|
||
|
|
ml.reason,
|
||
|
|
ml.rule_reference,
|
||
|
|
ml.evidence,
|
||
|
|
ml.duration_hours,
|
||
|
|
ml.expires_at,
|
||
|
|
ml.decision_type,
|
||
|
|
ml.vote_proposal_id,
|
||
|
|
ml.entry_hash,
|
||
|
|
ml.created_at,
|
||
|
|
CASE
|
||
|
|
WHEN ml.expires_at IS NULL THEN 'permanent'
|
||
|
|
WHEN ml.expires_at > NOW() THEN 'active'
|
||
|
|
ELSE 'expired'
|
||
|
|
END AS status
|
||
|
|
FROM moderation_ledger ml
|
||
|
|
LEFT JOIN communities c ON c.id = ml.community_id
|
||
|
|
LEFT JOIN users u ON u.id = ml.actor_user_id;
|
||
|
|
|
||
|
|
-- Summary statistics
|
||
|
|
CREATE OR REPLACE VIEW v_moderation_stats AS
|
||
|
|
SELECT
|
||
|
|
community_id,
|
||
|
|
action_type,
|
||
|
|
decision_type,
|
||
|
|
COUNT(*) AS total_actions,
|
||
|
|
COUNT(DISTINCT actor_user_id) AS unique_actors,
|
||
|
|
COUNT(DISTINCT target_id) AS unique_targets,
|
||
|
|
MIN(created_at) AS first_action,
|
||
|
|
MAX(created_at) AS last_action
|
||
|
|
FROM moderation_ledger
|
||
|
|
GROUP BY community_id, action_type, decision_type;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- PLUGIN REGISTRATION
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
-- Register as a core, non-deactivatable plugin
|
||
|
|
INSERT INTO plugins (
|
||
|
|
name,
|
||
|
|
description,
|
||
|
|
version,
|
||
|
|
is_core,
|
||
|
|
is_active,
|
||
|
|
settings_schema
|
||
|
|
) VALUES (
|
||
|
|
'moderation_ledger',
|
||
|
|
'Immutable, cryptographically-chained log of all moderation decisions. This plugin cannot be deactivated as it is essential for transparency and accountability.',
|
||
|
|
'1.0.0',
|
||
|
|
true, -- Core plugin
|
||
|
|
true, -- Always active
|
||
|
|
jsonb_build_object(
|
||
|
|
'type', 'object',
|
||
|
|
'properties', jsonb_build_object(
|
||
|
|
'require_reason_min_length', jsonb_build_object(
|
||
|
|
'type', 'integer',
|
||
|
|
'title', 'Minimum reason length',
|
||
|
|
'description', 'Minimum characters required for moderation justifications',
|
||
|
|
'default', 20,
|
||
|
|
'minimum', 10,
|
||
|
|
'maximum', 500
|
||
|
|
),
|
||
|
|
'require_rule_reference', jsonb_build_object(
|
||
|
|
'type', 'boolean',
|
||
|
|
'title', 'Require rule reference',
|
||
|
|
'description', 'Require moderators to cite a specific community rule',
|
||
|
|
'default', false
|
||
|
|
),
|
||
|
|
'snapshot_target_content', jsonb_build_object(
|
||
|
|
'type', 'boolean',
|
||
|
|
'title', 'Snapshot target content',
|
||
|
|
'description', 'Store a snapshot of content before moderation (uses more storage)',
|
||
|
|
'default', true
|
||
|
|
),
|
||
|
|
'public_ledger', jsonb_build_object(
|
||
|
|
'type', 'boolean',
|
||
|
|
'title', 'Public ledger',
|
||
|
|
'description', 'Allow all community members to view the moderation ledger',
|
||
|
|
'default', true
|
||
|
|
)
|
||
|
|
)
|
||
|
|
)
|
||
|
|
) ON CONFLICT (name) DO UPDATE SET
|
||
|
|
version = EXCLUDED.version,
|
||
|
|
description = EXCLUDED.description,
|
||
|
|
is_core = true,
|
||
|
|
is_active = true;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- COMMENTS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
COMMENT ON TABLE moderation_ledger IS 'Immutable, cryptographically-chained log of all moderation decisions. Entries cannot be modified or deleted (except for legal compliance).';
|
||
|
|
COMMENT ON COLUMN moderation_ledger.entry_hash IS 'SHA-256 hash of entry content, linked to previous entry hash forming a tamper-evident chain.';
|
||
|
|
COMMENT ON COLUMN moderation_ledger.previous_hash IS 'Hash of the previous entry in the chain, or genesis hash for first entry.';
|
||
|
|
COMMENT ON FUNCTION create_ledger_entry IS 'Creates a new ledger entry with automatic sequence numbering and hash chain maintenance.';
|
||
|
|
COMMENT ON FUNCTION verify_ledger_chain IS 'Verifies the cryptographic integrity of the entire ledger chain for a community.';
|