more audit work
This commit is contained in:
@@ -0,0 +1,108 @@
|
||||
-- OpsMemory and AdvisoryAI PostgreSQL Schema Migration
|
||||
-- Version: 20260108
|
||||
-- Author: StellaOps Agent
|
||||
-- Sprint: SPRINT_20260107_006_004 (OpsMemory), SPRINT_20260107_006_003 (AdvisoryAI)
|
||||
|
||||
-- ============================================================================
|
||||
-- OpsMemory Schema
|
||||
-- ============================================================================
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS opsmemory;
|
||||
|
||||
-- Decision records table
|
||||
CREATE TABLE IF NOT EXISTS opsmemory.decisions (
|
||||
memory_id TEXT PRIMARY KEY,
|
||||
tenant_id TEXT NOT NULL,
|
||||
recorded_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- Situation context
|
||||
cve_id TEXT,
|
||||
component_purl TEXT,
|
||||
severity TEXT,
|
||||
reachability TEXT,
|
||||
epss_score DECIMAL(5, 4),
|
||||
cvss_score DECIMAL(3, 1),
|
||||
context_tags TEXT[],
|
||||
similarity_vector DOUBLE PRECISION[],
|
||||
|
||||
-- Decision details
|
||||
action TEXT NOT NULL,
|
||||
rationale TEXT,
|
||||
decided_by TEXT NOT NULL,
|
||||
policy_reference TEXT,
|
||||
mitigation_type TEXT,
|
||||
mitigation_details TEXT,
|
||||
|
||||
-- Outcome (nullable until recorded)
|
||||
outcome_status TEXT,
|
||||
resolution_time INTERVAL,
|
||||
actual_impact TEXT,
|
||||
lessons_learned TEXT,
|
||||
outcome_recorded_by TEXT,
|
||||
outcome_recorded_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
-- Indexes for querying
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_tenant ON opsmemory.decisions(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_cve ON opsmemory.decisions(cve_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_component ON opsmemory.decisions(component_purl);
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_recorded ON opsmemory.decisions(recorded_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_action ON opsmemory.decisions(action);
|
||||
CREATE INDEX IF NOT EXISTS idx_opsmemory_decisions_outcome ON opsmemory.decisions(outcome_status);
|
||||
|
||||
-- ============================================================================
|
||||
-- AdvisoryAI Schema
|
||||
-- ============================================================================
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS advisoryai;
|
||||
|
||||
-- Conversations table
|
||||
CREATE TABLE IF NOT EXISTS advisoryai.conversations (
|
||||
conversation_id TEXT PRIMARY KEY,
|
||||
tenant_id TEXT NOT NULL,
|
||||
user_id TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
context JSONB,
|
||||
metadata JSONB
|
||||
);
|
||||
|
||||
-- Conversation turns table
|
||||
CREATE TABLE IF NOT EXISTS advisoryai.turns (
|
||||
turn_id TEXT PRIMARY KEY,
|
||||
conversation_id TEXT NOT NULL REFERENCES advisoryai.conversations(conversation_id) ON DELETE CASCADE,
|
||||
role TEXT NOT NULL,
|
||||
content TEXT NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
evidence_links JSONB,
|
||||
proposed_actions JSONB,
|
||||
metadata JSONB
|
||||
);
|
||||
|
||||
-- Indexes for querying
|
||||
CREATE INDEX IF NOT EXISTS idx_advisoryai_conv_tenant ON advisoryai.conversations(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisoryai_conv_user ON advisoryai.conversations(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisoryai_conv_updated ON advisoryai.conversations(updated_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisoryai_turns_conv ON advisoryai.turns(conversation_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisoryai_turns_timestamp ON advisoryai.turns(timestamp);
|
||||
|
||||
-- ============================================================================
|
||||
-- Comments for documentation
|
||||
-- ============================================================================
|
||||
|
||||
COMMENT ON SCHEMA opsmemory IS 'OpsMemory: Decision ledger for security playbook learning';
|
||||
COMMENT ON SCHEMA advisoryai IS 'AdvisoryAI: Chat conversation storage';
|
||||
|
||||
COMMENT ON TABLE opsmemory.decisions IS 'Stores security decisions and their outcomes for playbook suggestions';
|
||||
COMMENT ON TABLE advisoryai.conversations IS 'Stores AI chat conversations with context';
|
||||
COMMENT ON TABLE advisoryai.turns IS 'Individual messages in conversations';
|
||||
|
||||
-- ============================================================================
|
||||
-- Grants (adjust as needed for your environment)
|
||||
-- ============================================================================
|
||||
|
||||
-- GRANT USAGE ON SCHEMA opsmemory TO stellaops_app;
|
||||
-- GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA opsmemory TO stellaops_app;
|
||||
|
||||
-- GRANT USAGE ON SCHEMA advisoryai TO stellaops_app;
|
||||
-- GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA advisoryai TO stellaops_app;
|
||||
Reference in New Issue
Block a user