mirror of
https://codeberg.org/likwid/likwid.git
synced 2026-02-10 13:33:09 +00:00
254 lines
10 KiB
MySQL
254 lines
10 KiB
MySQL
|
|
-- ============================================================================
|
||
|
|
-- PUBLIC DATA EXPORT PLUGIN
|
||
|
|
-- CSV/JSON exports, complete datasets, privacy-aware, open data by default
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TYPE export_format AS ENUM ('json', 'csv', 'jsonl');
|
||
|
|
CREATE TYPE export_scope AS ENUM ('community', 'global', 'personal');
|
||
|
|
CREATE TYPE export_status AS ENUM ('pending', 'processing', 'completed', 'failed', 'expired');
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- EXPORT CONFIGURATIONS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE export_configurations (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE,
|
||
|
|
name VARCHAR(100) NOT NULL,
|
||
|
|
description TEXT,
|
||
|
|
export_type VARCHAR(50) NOT NULL,
|
||
|
|
default_format export_format NOT NULL DEFAULT 'json',
|
||
|
|
scope export_scope NOT NULL DEFAULT 'community',
|
||
|
|
anonymize_users BOOLEAN NOT NULL DEFAULT TRUE,
|
||
|
|
include_deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
||
|
|
redact_fields VARCHAR(100)[] DEFAULT '{}',
|
||
|
|
public_access BOOLEAN NOT NULL DEFAULT TRUE,
|
||
|
|
rate_limit_per_hour INT NOT NULL DEFAULT 10,
|
||
|
|
max_records INT NOT NULL DEFAULT 100000,
|
||
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
UNIQUE(community_id, name)
|
||
|
|
);
|
||
|
|
|
||
|
|
CREATE INDEX idx_export_configs_community ON export_configurations(community_id);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- EXPORT JOBS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE export_jobs (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
configuration_id UUID REFERENCES export_configurations(id) ON DELETE SET NULL,
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE,
|
||
|
|
export_type VARCHAR(50) NOT NULL,
|
||
|
|
format export_format NOT NULL DEFAULT 'json',
|
||
|
|
parameters JSONB DEFAULT '{}',
|
||
|
|
date_from TIMESTAMPTZ,
|
||
|
|
date_to TIMESTAMPTZ,
|
||
|
|
requested_by UUID REFERENCES users(id),
|
||
|
|
requested_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
status export_status NOT NULL DEFAULT 'pending',
|
||
|
|
started_at TIMESTAMPTZ,
|
||
|
|
completed_at TIMESTAMPTZ,
|
||
|
|
error_message TEXT,
|
||
|
|
record_count INT,
|
||
|
|
file_size_bytes BIGINT,
|
||
|
|
file_path TEXT,
|
||
|
|
download_url TEXT,
|
||
|
|
download_expires_at TIMESTAMPTZ,
|
||
|
|
download_count INT NOT NULL DEFAULT 0
|
||
|
|
);
|
||
|
|
|
||
|
|
CREATE INDEX idx_export_jobs_community ON export_jobs(community_id);
|
||
|
|
CREATE INDEX idx_export_jobs_status ON export_jobs(status);
|
||
|
|
CREATE INDEX idx_export_jobs_pending ON export_jobs(status, requested_at) WHERE status = 'pending';
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- SCHEDULED EXPORTS (pre-generated datasets)
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE scheduled_exports (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
configuration_id UUID NOT NULL REFERENCES export_configurations(id) ON DELETE CASCADE,
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE,
|
||
|
|
dataset_name VARCHAR(200) NOT NULL,
|
||
|
|
description TEXT,
|
||
|
|
generated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
data_from TIMESTAMPTZ,
|
||
|
|
data_to TIMESTAMPTZ,
|
||
|
|
json_file_path TEXT,
|
||
|
|
csv_file_path TEXT,
|
||
|
|
record_count INT NOT NULL,
|
||
|
|
checksum VARCHAR(64),
|
||
|
|
is_current BOOLEAN NOT NULL DEFAULT TRUE,
|
||
|
|
expires_at TIMESTAMPTZ
|
||
|
|
);
|
||
|
|
|
||
|
|
CREATE INDEX idx_scheduled_exports_current ON scheduled_exports(community_id, is_current) WHERE is_current = true;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- DATA DICTIONARY
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE export_data_dictionary (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
export_type VARCHAR(50) NOT NULL,
|
||
|
|
field_name VARCHAR(100) NOT NULL,
|
||
|
|
field_type VARCHAR(50) NOT NULL,
|
||
|
|
description TEXT NOT NULL,
|
||
|
|
is_pii BOOLEAN NOT NULL DEFAULT FALSE,
|
||
|
|
anonymization_method VARCHAR(50),
|
||
|
|
example_value TEXT,
|
||
|
|
UNIQUE(export_type, field_name)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- EXPORT AUDIT LOG
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE TABLE export_audit_log (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
job_id UUID REFERENCES export_jobs(id),
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE SET NULL,
|
||
|
|
action_type VARCHAR(50) NOT NULL,
|
||
|
|
actor_id UUID REFERENCES users(id),
|
||
|
|
ip_address INET,
|
||
|
|
user_agent TEXT,
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||
|
|
);
|
||
|
|
|
||
|
|
CREATE INDEX idx_export_audit_community ON export_audit_log(community_id);
|
||
|
|
CREATE INDEX idx_export_audit_time ON export_audit_log(created_at);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- DEFAULT CONFIGURATIONS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
INSERT INTO export_data_dictionary (export_type, field_name, field_type, description, is_pii, anonymization_method) VALUES
|
||
|
|
('proposals', 'id', 'uuid', 'Unique proposal identifier', false, null),
|
||
|
|
('proposals', 'title', 'string', 'Proposal title', false, null),
|
||
|
|
('proposals', 'content', 'text', 'Full proposal content', false, null),
|
||
|
|
('proposals', 'author_id', 'uuid', 'Author identifier (anonymized)', true, 'hash'),
|
||
|
|
('proposals', 'status', 'string', 'Current proposal status', false, null),
|
||
|
|
('proposals', 'created_at', 'timestamp', 'Creation timestamp', false, null),
|
||
|
|
('proposals', 'vote_count', 'integer', 'Total votes received', false, null),
|
||
|
|
('votes', 'id', 'uuid', 'Unique vote identifier', false, null),
|
||
|
|
('votes', 'proposal_id', 'uuid', 'Associated proposal', false, null),
|
||
|
|
('votes', 'voter_id', 'uuid', 'Voter identifier (anonymized)', true, 'hash'),
|
||
|
|
('votes', 'vote_value', 'jsonb', 'Vote data (method-specific)', false, null),
|
||
|
|
('votes', 'created_at', 'timestamp', 'Vote timestamp', false, null),
|
||
|
|
('analytics', 'date', 'date', 'Metric date', false, null),
|
||
|
|
('analytics', 'metric_name', 'string', 'Metric identifier', false, null),
|
||
|
|
('analytics', 'value', 'numeric', 'Metric value', false, null);
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- HELPER FUNCTIONS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION create_export_job(
|
||
|
|
p_community_id UUID,
|
||
|
|
p_export_type VARCHAR(50),
|
||
|
|
p_format export_format,
|
||
|
|
p_requested_by UUID,
|
||
|
|
p_date_from TIMESTAMPTZ DEFAULT NULL,
|
||
|
|
p_date_to TIMESTAMPTZ DEFAULT NULL
|
||
|
|
) RETURNS UUID AS $$
|
||
|
|
DECLARE
|
||
|
|
v_job_id UUID;
|
||
|
|
v_config export_configurations%ROWTYPE;
|
||
|
|
BEGIN
|
||
|
|
SELECT * INTO v_config FROM export_configurations
|
||
|
|
WHERE community_id = p_community_id AND export_type = p_export_type AND is_active
|
||
|
|
LIMIT 1;
|
||
|
|
|
||
|
|
INSERT INTO export_jobs (
|
||
|
|
configuration_id, community_id, export_type, format,
|
||
|
|
date_from, date_to, requested_by
|
||
|
|
) VALUES (
|
||
|
|
v_config.id, p_community_id, p_export_type, p_format,
|
||
|
|
p_date_from, p_date_to, p_requested_by
|
||
|
|
) RETURNING id INTO v_job_id;
|
||
|
|
|
||
|
|
INSERT INTO export_audit_log (job_id, community_id, action_type, actor_id)
|
||
|
|
VALUES (v_job_id, p_community_id, 'requested', p_requested_by);
|
||
|
|
|
||
|
|
RETURN v_job_id;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION get_exportable_proposals(
|
||
|
|
p_community_id UUID,
|
||
|
|
p_anonymize BOOLEAN DEFAULT TRUE,
|
||
|
|
p_date_from TIMESTAMPTZ DEFAULT NULL,
|
||
|
|
p_date_to TIMESTAMPTZ DEFAULT NULL
|
||
|
|
) RETURNS TABLE (
|
||
|
|
id UUID,
|
||
|
|
title VARCHAR,
|
||
|
|
content TEXT,
|
||
|
|
author_id TEXT,
|
||
|
|
status VARCHAR,
|
||
|
|
created_at TIMESTAMPTZ,
|
||
|
|
vote_count BIGINT
|
||
|
|
) AS $$
|
||
|
|
BEGIN
|
||
|
|
RETURN QUERY
|
||
|
|
SELECT
|
||
|
|
p.id,
|
||
|
|
p.title,
|
||
|
|
p.content,
|
||
|
|
CASE WHEN p_anonymize THEN encode(sha256(p.author_id::text::bytea), 'hex') ELSE p.author_id::text END,
|
||
|
|
p.status::VARCHAR,
|
||
|
|
p.created_at,
|
||
|
|
COALESCE((SELECT COUNT(*) FROM votes v WHERE v.proposal_id = p.id), 0)
|
||
|
|
FROM proposals p
|
||
|
|
WHERE p.community_id = p_community_id
|
||
|
|
AND (p_date_from IS NULL OR p.created_at >= p_date_from)
|
||
|
|
AND (p_date_to IS NULL OR p.created_at <= p_date_to)
|
||
|
|
ORDER BY p.created_at DESC;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- VIEWS
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
CREATE OR REPLACE VIEW available_exports AS
|
||
|
|
SELECT
|
||
|
|
ec.id AS config_id,
|
||
|
|
ec.community_id,
|
||
|
|
c.name AS community_name,
|
||
|
|
ec.name AS export_name,
|
||
|
|
ec.description,
|
||
|
|
ec.export_type,
|
||
|
|
ec.public_access,
|
||
|
|
se.id AS latest_export_id,
|
||
|
|
se.generated_at AS latest_generated,
|
||
|
|
se.record_count AS latest_record_count
|
||
|
|
FROM export_configurations ec
|
||
|
|
JOIN communities c ON c.id = ec.community_id
|
||
|
|
LEFT JOIN scheduled_exports se ON se.configuration_id = ec.id AND se.is_current = true
|
||
|
|
WHERE ec.is_active = true;
|
||
|
|
|
||
|
|
-- ============================================================================
|
||
|
|
-- PLUGIN REGISTRATION
|
||
|
|
-- ============================================================================
|
||
|
|
|
||
|
|
INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema)
|
||
|
|
VALUES (
|
||
|
|
'public_data_export',
|
||
|
|
'Privacy-aware public data exports in CSV/JSON formats. Supports anonymization, scheduled generation, and complete audit trails.',
|
||
|
|
'1.0.0',
|
||
|
|
false,
|
||
|
|
true,
|
||
|
|
jsonb_build_object(
|
||
|
|
'type', 'object',
|
||
|
|
'properties', jsonb_build_object(
|
||
|
|
'default_anonymize', jsonb_build_object('type', 'boolean', 'default', true),
|
||
|
|
'allow_public_exports', jsonb_build_object('type', 'boolean', 'default', true),
|
||
|
|
'max_export_records', jsonb_build_object('type', 'integer', 'default', 100000),
|
||
|
|
'export_retention_days', jsonb_build_object('type', 'integer', 'default', 30),
|
||
|
|
'auto_generate_daily', jsonb_build_object('type', 'boolean', 'default', false)
|
||
|
|
)
|
||
|
|
)
|
||
|
|
) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version;
|