-- Plugin Key-Value Store for WASM plugins -- Provides persistent storage for plugin data with isolation per plugin/community CREATE TABLE plugin_kv_store ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Plugin identification plugin_name VARCHAR(255) NOT NULL, -- Optional community scope (NULL = global/instance-level) community_id UUID REFERENCES communities(id) ON DELETE CASCADE, -- Key-value pair key VARCHAR(512) NOT NULL, value JSONB NOT NULL DEFAULT '{}', -- Metadata created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ, -- Optional TTL -- Unique constraint per plugin/community/key combination UNIQUE(plugin_name, community_id, key) ); -- Index for fast lookups CREATE INDEX idx_plugin_kv_plugin ON plugin_kv_store(plugin_name); CREATE INDEX idx_plugin_kv_community ON plugin_kv_store(community_id); CREATE INDEX idx_plugin_kv_lookup ON plugin_kv_store(plugin_name, community_id, key); CREATE INDEX idx_plugin_kv_expires ON plugin_kv_store(expires_at) WHERE expires_at IS NOT NULL; -- Plugin events table for event emission CREATE TABLE plugin_events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Event source plugin_name VARCHAR(255) NOT NULL, community_id UUID REFERENCES communities(id) ON DELETE CASCADE, actor_user_id UUID REFERENCES users(id) ON DELETE SET NULL, -- Event data event_name VARCHAR(255) NOT NULL, payload JSONB NOT NULL DEFAULT '{}', -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), -- Processing status (for async event handlers) processed BOOLEAN DEFAULT FALSE, processed_at TIMESTAMPTZ ); -- Index for event queries CREATE INDEX idx_plugin_events_name ON plugin_events(event_name); CREATE INDEX idx_plugin_events_plugin ON plugin_events(plugin_name); CREATE INDEX idx_plugin_events_community ON plugin_events(community_id); CREATE INDEX idx_plugin_events_unprocessed ON plugin_events(processed) WHERE processed = FALSE; CREATE INDEX idx_plugin_events_created ON plugin_events(created_at DESC); -- Function to get plugin setting CREATE OR REPLACE FUNCTION get_plugin_setting( p_plugin_name VARCHAR(255), p_community_id UUID, p_key VARCHAR(255) ) RETURNS JSONB AS $$ DECLARE v_setting JSONB; BEGIN -- First try community-specific setting IF p_community_id IS NOT NULL THEN SELECT settings->p_key INTO v_setting FROM community_plugins cp JOIN plugins p ON p.id = cp.plugin_id WHERE p.name = p_plugin_name AND cp.community_id = p_community_id; IF v_setting IS NOT NULL THEN RETURN v_setting; END IF; END IF; -- Fall back to plugin default settings SELECT default_settings->p_key INTO v_setting FROM plugins WHERE name = p_plugin_name; RETURN COALESCE(v_setting, 'null'::jsonb); END; $$ LANGUAGE plpgsql; -- Function to set KV value CREATE OR REPLACE FUNCTION plugin_kv_set( p_plugin_name VARCHAR(255), p_community_id UUID, p_key VARCHAR(512), p_value JSONB, p_ttl_seconds INTEGER DEFAULT NULL ) RETURNS BOOLEAN AS $$ DECLARE v_expires_at TIMESTAMPTZ; BEGIN IF p_ttl_seconds IS NOT NULL THEN v_expires_at := NOW() + (p_ttl_seconds || ' seconds')::interval; END IF; INSERT INTO plugin_kv_store (plugin_name, community_id, key, value, expires_at) VALUES (p_plugin_name, p_community_id, p_key, p_value, v_expires_at) ON CONFLICT (plugin_name, community_id, key) DO UPDATE SET value = EXCLUDED.value, updated_at = NOW(), expires_at = EXCLUDED.expires_at; RETURN TRUE; END; $$ LANGUAGE plpgsql; -- Function to get KV value CREATE OR REPLACE FUNCTION plugin_kv_get( p_plugin_name VARCHAR(255), p_community_id UUID, p_key VARCHAR(512) ) RETURNS JSONB AS $$ DECLARE v_value JSONB; BEGIN SELECT value INTO v_value FROM plugin_kv_store WHERE plugin_name = p_plugin_name AND (community_id = p_community_id OR (p_community_id IS NULL AND community_id IS NULL)) AND key = p_key AND (expires_at IS NULL OR expires_at > NOW()); RETURN v_value; END; $$ LANGUAGE plpgsql; -- Function to delete KV value CREATE OR REPLACE FUNCTION plugin_kv_delete( p_plugin_name VARCHAR(255), p_community_id UUID, p_key VARCHAR(512) ) RETURNS BOOLEAN AS $$ BEGIN DELETE FROM plugin_kv_store WHERE plugin_name = p_plugin_name AND (community_id = p_community_id OR (p_community_id IS NULL AND community_id IS NULL)) AND key = p_key; RETURN FOUND; END; $$ LANGUAGE plpgsql; -- Cleanup job for expired KV entries (to be run periodically) CREATE OR REPLACE FUNCTION cleanup_expired_plugin_kv() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER; BEGIN DELETE FROM plugin_kv_store WHERE expires_at IS NOT NULL AND expires_at < NOW(); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END; $$ LANGUAGE plpgsql;