up
This commit is contained in:
@@ -0,0 +1,50 @@
|
||||
using Microsoft.Extensions.Logging;
|
||||
using Microsoft.Extensions.Options;
|
||||
using Npgsql;
|
||||
using StellaOps.Infrastructure.Postgres.Connections;
|
||||
using StellaOps.Infrastructure.Postgres.Options;
|
||||
|
||||
namespace StellaOps.Concelier.Storage.Postgres;
|
||||
|
||||
/// <summary>
|
||||
/// PostgreSQL data source for the Concelier (vulnerability) module.
|
||||
/// Manages connections for advisory ingestion, merging, and vulnerability data.
|
||||
/// </summary>
|
||||
/// <remarks>
|
||||
/// The Concelier module stores global vulnerability data that is not tenant-scoped.
|
||||
/// Advisories and their metadata are shared across all tenants.
|
||||
/// </remarks>
|
||||
public sealed class ConcelierDataSource : DataSourceBase
|
||||
{
|
||||
/// <summary>
|
||||
/// Default schema name for Concelier/vulnerability tables.
|
||||
/// </summary>
|
||||
public const string DefaultSchemaName = "vuln";
|
||||
|
||||
/// <summary>
|
||||
/// Creates a new Concelier data source.
|
||||
/// </summary>
|
||||
public ConcelierDataSource(IOptions<PostgresOptions> options, ILogger<ConcelierDataSource> logger)
|
||||
: base(CreateOptions(options.Value), logger)
|
||||
{
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
protected override string ModuleName => "Concelier";
|
||||
|
||||
/// <inheritdoc />
|
||||
protected override void ConfigureDataSourceBuilder(NpgsqlDataSourceBuilder builder)
|
||||
{
|
||||
base.ConfigureDataSourceBuilder(builder);
|
||||
// Enable full-text search vector support for advisory searching
|
||||
}
|
||||
|
||||
private static PostgresOptions CreateOptions(PostgresOptions baseOptions)
|
||||
{
|
||||
if (string.IsNullOrWhiteSpace(baseOptions.SchemaName))
|
||||
{
|
||||
baseOptions.SchemaName = DefaultSchemaName;
|
||||
}
|
||||
return baseOptions;
|
||||
}
|
||||
}
|
||||
@@ -0,0 +1,261 @@
|
||||
-- Vulnerability Schema Migration 001: Initial Schema
|
||||
-- Creates the vuln schema for advisories and vulnerability data
|
||||
|
||||
-- Create schema
|
||||
CREATE SCHEMA IF NOT EXISTS vuln;
|
||||
|
||||
-- Enable pg_trgm for fuzzy text search
|
||||
CREATE EXTENSION IF NOT EXISTS pg_trgm;
|
||||
|
||||
-- Sources table (feed sources)
|
||||
CREATE TABLE IF NOT EXISTS vuln.sources (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
name TEXT NOT NULL,
|
||||
source_type TEXT NOT NULL,
|
||||
url TEXT,
|
||||
priority INT NOT NULL DEFAULT 0,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
config JSONB NOT NULL DEFAULT '{}',
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sources_enabled ON vuln.sources(enabled, priority DESC);
|
||||
|
||||
-- Feed snapshots table
|
||||
CREATE TABLE IF NOT EXISTS vuln.feed_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id),
|
||||
snapshot_id TEXT NOT NULL,
|
||||
advisory_count INT NOT NULL DEFAULT 0,
|
||||
checksum TEXT,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(source_id, snapshot_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_feed_snapshots_source ON vuln.feed_snapshots(source_id);
|
||||
CREATE INDEX idx_feed_snapshots_created ON vuln.feed_snapshots(created_at);
|
||||
|
||||
-- Advisory snapshots table (point-in-time snapshots)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
feed_snapshot_id UUID NOT NULL REFERENCES vuln.feed_snapshots(id),
|
||||
advisory_key TEXT NOT NULL,
|
||||
content_hash TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(feed_snapshot_id, advisory_key)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_snapshots_feed ON vuln.advisory_snapshots(feed_snapshot_id);
|
||||
CREATE INDEX idx_advisory_snapshots_key ON vuln.advisory_snapshots(advisory_key);
|
||||
|
||||
-- Advisories table (main vulnerability data)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisories (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_key TEXT NOT NULL UNIQUE,
|
||||
primary_vuln_id TEXT NOT NULL,
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
title TEXT,
|
||||
summary TEXT,
|
||||
description TEXT,
|
||||
severity TEXT CHECK (severity IN ('critical', 'high', 'medium', 'low', 'unknown')),
|
||||
published_at TIMESTAMPTZ,
|
||||
modified_at TIMESTAMPTZ,
|
||||
withdrawn_at TIMESTAMPTZ,
|
||||
provenance JSONB NOT NULL DEFAULT '{}',
|
||||
raw_payload JSONB,
|
||||
search_vector TSVECTOR,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisories_vuln_id ON vuln.advisories(primary_vuln_id);
|
||||
CREATE INDEX idx_advisories_source ON vuln.advisories(source_id);
|
||||
CREATE INDEX idx_advisories_severity ON vuln.advisories(severity);
|
||||
CREATE INDEX idx_advisories_published ON vuln.advisories(published_at);
|
||||
CREATE INDEX idx_advisories_modified ON vuln.advisories(modified_at);
|
||||
CREATE INDEX idx_advisories_search ON vuln.advisories USING GIN(search_vector);
|
||||
|
||||
-- Advisory aliases table (CVE, GHSA, etc.)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_aliases (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
alias_type TEXT NOT NULL,
|
||||
alias_value TEXT NOT NULL,
|
||||
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, alias_type, alias_value)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_aliases_advisory ON vuln.advisory_aliases(advisory_id);
|
||||
CREATE INDEX idx_advisory_aliases_value ON vuln.advisory_aliases(alias_type, alias_value);
|
||||
CREATE INDEX idx_advisory_aliases_cve ON vuln.advisory_aliases(alias_value)
|
||||
WHERE alias_type = 'CVE';
|
||||
|
||||
-- Advisory CVSS scores table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_cvss (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cvss_version TEXT NOT NULL,
|
||||
vector_string TEXT NOT NULL,
|
||||
base_score NUMERIC(3,1) NOT NULL,
|
||||
base_severity TEXT,
|
||||
exploitability_score NUMERIC(3,1),
|
||||
impact_score NUMERIC(3,1),
|
||||
source TEXT,
|
||||
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cvss_version, source)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_cvss_advisory ON vuln.advisory_cvss(advisory_id);
|
||||
CREATE INDEX idx_advisory_cvss_score ON vuln.advisory_cvss(base_score DESC);
|
||||
|
||||
-- Advisory affected packages table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_affected (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
ecosystem TEXT NOT NULL,
|
||||
package_name TEXT NOT NULL,
|
||||
purl TEXT,
|
||||
version_range JSONB NOT NULL DEFAULT '{}',
|
||||
versions_affected TEXT[],
|
||||
versions_fixed TEXT[],
|
||||
database_specific JSONB,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_affected_advisory ON vuln.advisory_affected(advisory_id);
|
||||
CREATE INDEX idx_advisory_affected_ecosystem ON vuln.advisory_affected(ecosystem, package_name);
|
||||
CREATE INDEX idx_advisory_affected_purl ON vuln.advisory_affected(purl);
|
||||
CREATE INDEX idx_advisory_affected_purl_trgm ON vuln.advisory_affected USING GIN(purl gin_trgm_ops);
|
||||
|
||||
-- Advisory references table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_references (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
ref_type TEXT NOT NULL,
|
||||
url TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_references_advisory ON vuln.advisory_references(advisory_id);
|
||||
|
||||
-- Advisory credits table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_credits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
contact TEXT,
|
||||
credit_type TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_credits_advisory ON vuln.advisory_credits(advisory_id);
|
||||
|
||||
-- Advisory weaknesses table (CWE)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_weaknesses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cwe_id TEXT NOT NULL,
|
||||
description TEXT,
|
||||
source TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cwe_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_weaknesses_advisory ON vuln.advisory_weaknesses(advisory_id);
|
||||
CREATE INDEX idx_advisory_weaknesses_cwe ON vuln.advisory_weaknesses(cwe_id);
|
||||
|
||||
-- KEV flags table (Known Exploited Vulnerabilities)
|
||||
CREATE TABLE IF NOT EXISTS vuln.kev_flags (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cve_id TEXT NOT NULL,
|
||||
vendor_project TEXT,
|
||||
product TEXT,
|
||||
vulnerability_name TEXT,
|
||||
date_added DATE NOT NULL,
|
||||
due_date DATE,
|
||||
known_ransomware_use BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cve_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_kev_flags_advisory ON vuln.kev_flags(advisory_id);
|
||||
CREATE INDEX idx_kev_flags_cve ON vuln.kev_flags(cve_id);
|
||||
CREATE INDEX idx_kev_flags_date ON vuln.kev_flags(date_added);
|
||||
|
||||
-- Source states table (cursor tracking)
|
||||
CREATE TABLE IF NOT EXISTS vuln.source_states (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id) UNIQUE,
|
||||
cursor TEXT,
|
||||
last_sync_at TIMESTAMPTZ,
|
||||
last_success_at TIMESTAMPTZ,
|
||||
last_error TEXT,
|
||||
sync_count BIGINT NOT NULL DEFAULT 0,
|
||||
error_count INT NOT NULL DEFAULT 0,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_source_states_source ON vuln.source_states(source_id);
|
||||
|
||||
-- Merge events table (advisory merge audit)
|
||||
CREATE TABLE IF NOT EXISTS vuln.merge_events (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id),
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
event_type TEXT NOT NULL,
|
||||
old_value JSONB,
|
||||
new_value JSONB,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_merge_events_advisory ON vuln.merge_events(advisory_id);
|
||||
CREATE INDEX idx_merge_events_created ON vuln.merge_events(created_at);
|
||||
|
||||
-- Function to update search vector
|
||||
CREATE OR REPLACE FUNCTION vuln.update_advisory_search_vector()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.search_vector =
|
||||
setweight(to_tsvector('english', COALESCE(NEW.primary_vuln_id, '')), 'A') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.title, '')), 'B') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.summary, '')), 'C') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.description, '')), 'D');
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Trigger for search vector
|
||||
CREATE TRIGGER trg_advisories_search_vector
|
||||
BEFORE INSERT OR UPDATE ON vuln.advisories
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_advisory_search_vector();
|
||||
|
||||
-- Update timestamp function
|
||||
CREATE OR REPLACE FUNCTION vuln.update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Triggers
|
||||
CREATE TRIGGER trg_sources_updated_at
|
||||
BEFORE UPDATE ON vuln.sources
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_advisories_updated_at
|
||||
BEFORE UPDATE ON vuln.advisories
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_source_states_updated_at
|
||||
BEFORE UPDATE ON vuln.source_states
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
@@ -0,0 +1,82 @@
|
||||
namespace StellaOps.Concelier.Storage.Postgres.Models;
|
||||
|
||||
/// <summary>
|
||||
/// Represents an advisory entity in the vuln schema.
|
||||
/// </summary>
|
||||
public sealed class AdvisoryEntity
|
||||
{
|
||||
/// <summary>
|
||||
/// Unique advisory identifier.
|
||||
/// </summary>
|
||||
public required Guid Id { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Advisory key (unique identifier, e.g., "ghsa:GHSA-xxxx").
|
||||
/// </summary>
|
||||
public required string AdvisoryKey { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Primary vulnerability ID (CVE, GHSA, etc.).
|
||||
/// </summary>
|
||||
public required string PrimaryVulnId { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Source that provided this advisory.
|
||||
/// </summary>
|
||||
public Guid? SourceId { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Advisory title.
|
||||
/// </summary>
|
||||
public string? Title { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Brief summary.
|
||||
/// </summary>
|
||||
public string? Summary { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Full description.
|
||||
/// </summary>
|
||||
public string? Description { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Severity level.
|
||||
/// </summary>
|
||||
public string? Severity { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the advisory was published.
|
||||
/// </summary>
|
||||
public DateTimeOffset? PublishedAt { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the advisory was last modified.
|
||||
/// </summary>
|
||||
public DateTimeOffset? ModifiedAt { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the advisory was withdrawn (if applicable).
|
||||
/// </summary>
|
||||
public DateTimeOffset? WithdrawnAt { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Provenance information as JSON.
|
||||
/// </summary>
|
||||
public string Provenance { get; init; } = "{}";
|
||||
|
||||
/// <summary>
|
||||
/// Raw payload from the source as JSON.
|
||||
/// </summary>
|
||||
public string? RawPayload { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the record was created.
|
||||
/// </summary>
|
||||
public DateTimeOffset CreatedAt { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the record was last updated.
|
||||
/// </summary>
|
||||
public DateTimeOffset UpdatedAt { get; init; }
|
||||
}
|
||||
@@ -0,0 +1,62 @@
|
||||
namespace StellaOps.Concelier.Storage.Postgres.Models;
|
||||
|
||||
/// <summary>
|
||||
/// Represents a vulnerability feed source entity.
|
||||
/// </summary>
|
||||
public sealed class SourceEntity
|
||||
{
|
||||
/// <summary>
|
||||
/// Unique source identifier.
|
||||
/// </summary>
|
||||
public required Guid Id { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Unique source key (e.g., "nvd", "ghsa", "osv").
|
||||
/// </summary>
|
||||
public required string Key { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Display name.
|
||||
/// </summary>
|
||||
public required string Name { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Source type (e.g., "nvd", "osv", "github").
|
||||
/// </summary>
|
||||
public required string SourceType { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Source URL.
|
||||
/// </summary>
|
||||
public string? Url { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Priority for merge precedence (higher = more authoritative).
|
||||
/// </summary>
|
||||
public int Priority { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// Source is enabled.
|
||||
/// </summary>
|
||||
public bool Enabled { get; init; } = true;
|
||||
|
||||
/// <summary>
|
||||
/// Source-specific configuration as JSON.
|
||||
/// </summary>
|
||||
public string Config { get; init; } = "{}";
|
||||
|
||||
/// <summary>
|
||||
/// Source metadata as JSON.
|
||||
/// </summary>
|
||||
public string Metadata { get; init; } = "{}";
|
||||
|
||||
/// <summary>
|
||||
/// When the record was created.
|
||||
/// </summary>
|
||||
public DateTimeOffset CreatedAt { get; init; }
|
||||
|
||||
/// <summary>
|
||||
/// When the record was last updated.
|
||||
/// </summary>
|
||||
public DateTimeOffset UpdatedAt { get; init; }
|
||||
}
|
||||
@@ -0,0 +1,320 @@
|
||||
using Microsoft.Extensions.Logging;
|
||||
using Npgsql;
|
||||
using StellaOps.Concelier.Storage.Postgres.Models;
|
||||
using StellaOps.Infrastructure.Postgres.Repositories;
|
||||
|
||||
namespace StellaOps.Concelier.Storage.Postgres.Repositories;
|
||||
|
||||
/// <summary>
|
||||
/// PostgreSQL repository for advisory operations.
|
||||
/// </summary>
|
||||
/// <remarks>
|
||||
/// Advisory data is global (not tenant-scoped) as vulnerability information
|
||||
/// is shared across all tenants.
|
||||
/// </remarks>
|
||||
public sealed class AdvisoryRepository : RepositoryBase<ConcelierDataSource>, IAdvisoryRepository
|
||||
{
|
||||
private const string SystemTenantId = "_system";
|
||||
|
||||
/// <summary>
|
||||
/// Creates a new advisory repository.
|
||||
/// </summary>
|
||||
public AdvisoryRepository(ConcelierDataSource dataSource, ILogger<AdvisoryRepository> logger)
|
||||
: base(dataSource, logger)
|
||||
{
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<AdvisoryEntity> UpsertAsync(AdvisoryEntity advisory, CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
INSERT INTO vuln.advisories (
|
||||
id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance, raw_payload
|
||||
)
|
||||
VALUES (
|
||||
@id, @advisory_key, @primary_vuln_id, @source_id, @title, @summary, @description,
|
||||
@severity, @published_at, @modified_at, @withdrawn_at, @provenance::jsonb, @raw_payload::jsonb
|
||||
)
|
||||
ON CONFLICT (advisory_key) DO UPDATE SET
|
||||
primary_vuln_id = EXCLUDED.primary_vuln_id,
|
||||
source_id = COALESCE(EXCLUDED.source_id, vuln.advisories.source_id),
|
||||
title = COALESCE(EXCLUDED.title, vuln.advisories.title),
|
||||
summary = COALESCE(EXCLUDED.summary, vuln.advisories.summary),
|
||||
description = COALESCE(EXCLUDED.description, vuln.advisories.description),
|
||||
severity = COALESCE(EXCLUDED.severity, vuln.advisories.severity),
|
||||
published_at = COALESCE(EXCLUDED.published_at, vuln.advisories.published_at),
|
||||
modified_at = COALESCE(EXCLUDED.modified_at, vuln.advisories.modified_at),
|
||||
withdrawn_at = EXCLUDED.withdrawn_at,
|
||||
provenance = vuln.advisories.provenance || EXCLUDED.provenance,
|
||||
raw_payload = EXCLUDED.raw_payload
|
||||
RETURNING id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
""";
|
||||
|
||||
await using var connection = await DataSource.OpenSystemConnectionAsync(cancellationToken).ConfigureAwait(false);
|
||||
await using var command = CreateCommand(sql, connection);
|
||||
|
||||
AddParameter(command, "id", advisory.Id);
|
||||
AddParameter(command, "advisory_key", advisory.AdvisoryKey);
|
||||
AddParameter(command, "primary_vuln_id", advisory.PrimaryVulnId);
|
||||
AddParameter(command, "source_id", advisory.SourceId);
|
||||
AddParameter(command, "title", advisory.Title);
|
||||
AddParameter(command, "summary", advisory.Summary);
|
||||
AddParameter(command, "description", advisory.Description);
|
||||
AddParameter(command, "severity", advisory.Severity);
|
||||
AddParameter(command, "published_at", advisory.PublishedAt);
|
||||
AddParameter(command, "modified_at", advisory.ModifiedAt);
|
||||
AddParameter(command, "withdrawn_at", advisory.WithdrawnAt);
|
||||
AddJsonbParameter(command, "provenance", advisory.Provenance);
|
||||
AddJsonbParameter(command, "raw_payload", advisory.RawPayload);
|
||||
|
||||
await using var reader = await command.ExecuteReaderAsync(cancellationToken).ConfigureAwait(false);
|
||||
await reader.ReadAsync(cancellationToken).ConfigureAwait(false);
|
||||
|
||||
return MapAdvisory(reader);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<AdvisoryEntity?> GetByIdAsync(Guid id, CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE id = @id
|
||||
""";
|
||||
|
||||
return await QuerySingleOrDefaultAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd => AddParameter(cmd, "id", id),
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<AdvisoryEntity?> GetByKeyAsync(string advisoryKey, CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE advisory_key = @advisory_key
|
||||
""";
|
||||
|
||||
return await QuerySingleOrDefaultAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd => AddParameter(cmd, "advisory_key", advisoryKey),
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<AdvisoryEntity?> GetByVulnIdAsync(string vulnId, CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE primary_vuln_id = @vuln_id
|
||||
""";
|
||||
|
||||
return await QuerySingleOrDefaultAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd => AddParameter(cmd, "vuln_id", vulnId),
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<IReadOnlyList<AdvisoryEntity>> SearchAsync(
|
||||
string query,
|
||||
string? severity = null,
|
||||
int limit = 50,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default)
|
||||
{
|
||||
var sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at,
|
||||
ts_rank(search_vector, websearch_to_tsquery('english', @query)) as rank
|
||||
FROM vuln.advisories
|
||||
WHERE search_vector @@ websearch_to_tsquery('english', @query)
|
||||
""";
|
||||
|
||||
if (!string.IsNullOrEmpty(severity))
|
||||
{
|
||||
sql += " AND severity = @severity";
|
||||
}
|
||||
|
||||
sql += " ORDER BY rank DESC, modified_at DESC, id LIMIT @limit OFFSET @offset";
|
||||
|
||||
return await QueryAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd =>
|
||||
{
|
||||
AddParameter(cmd, "query", query);
|
||||
if (!string.IsNullOrEmpty(severity))
|
||||
{
|
||||
AddParameter(cmd, "severity", severity);
|
||||
}
|
||||
AddParameter(cmd, "limit", limit);
|
||||
AddParameter(cmd, "offset", offset);
|
||||
},
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<IReadOnlyList<AdvisoryEntity>> GetBySeverityAsync(
|
||||
string severity,
|
||||
int limit = 100,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE severity = @severity
|
||||
ORDER BY modified_at DESC, id
|
||||
LIMIT @limit OFFSET @offset
|
||||
""";
|
||||
|
||||
return await QueryAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd =>
|
||||
{
|
||||
AddParameter(cmd, "severity", severity);
|
||||
AddParameter(cmd, "limit", limit);
|
||||
AddParameter(cmd, "offset", offset);
|
||||
},
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<IReadOnlyList<AdvisoryEntity>> GetModifiedSinceAsync(
|
||||
DateTimeOffset since,
|
||||
int limit = 1000,
|
||||
CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE modified_at > @since
|
||||
ORDER BY modified_at, id
|
||||
LIMIT @limit
|
||||
""";
|
||||
|
||||
return await QueryAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd =>
|
||||
{
|
||||
AddParameter(cmd, "since", since);
|
||||
AddParameter(cmd, "limit", limit);
|
||||
},
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<IReadOnlyList<AdvisoryEntity>> GetBySourceAsync(
|
||||
Guid sourceId,
|
||||
int limit = 100,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT id, advisory_key, primary_vuln_id, source_id, title, summary, description,
|
||||
severity, published_at, modified_at, withdrawn_at, provenance::text, raw_payload::text,
|
||||
created_at, updated_at
|
||||
FROM vuln.advisories
|
||||
WHERE source_id = @source_id
|
||||
ORDER BY modified_at DESC, id
|
||||
LIMIT @limit OFFSET @offset
|
||||
""";
|
||||
|
||||
return await QueryAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
cmd =>
|
||||
{
|
||||
AddParameter(cmd, "source_id", sourceId);
|
||||
AddParameter(cmd, "limit", limit);
|
||||
AddParameter(cmd, "offset", offset);
|
||||
},
|
||||
MapAdvisory,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<long> CountAsync(CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = "SELECT COUNT(*) FROM vuln.advisories";
|
||||
|
||||
var result = await ExecuteScalarAsync<long>(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
null,
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
|
||||
return result;
|
||||
}
|
||||
|
||||
/// <inheritdoc />
|
||||
public async Task<IDictionary<string, long>> CountBySeverityAsync(CancellationToken cancellationToken = default)
|
||||
{
|
||||
const string sql = """
|
||||
SELECT COALESCE(severity, 'unknown') as severity, COUNT(*) as count
|
||||
FROM vuln.advisories
|
||||
GROUP BY severity
|
||||
ORDER BY severity
|
||||
""";
|
||||
|
||||
var results = await QueryAsync(
|
||||
SystemTenantId,
|
||||
sql,
|
||||
null,
|
||||
reader => (
|
||||
Severity: reader.GetString(0),
|
||||
Count: reader.GetInt64(1)
|
||||
),
|
||||
cancellationToken).ConfigureAwait(false);
|
||||
|
||||
return results.ToDictionary(r => r.Severity, r => r.Count);
|
||||
}
|
||||
|
||||
private static AdvisoryEntity MapAdvisory(NpgsqlDataReader reader) => new()
|
||||
{
|
||||
Id = reader.GetGuid(0),
|
||||
AdvisoryKey = reader.GetString(1),
|
||||
PrimaryVulnId = reader.GetString(2),
|
||||
SourceId = GetNullableGuid(reader, 3),
|
||||
Title = GetNullableString(reader, 4),
|
||||
Summary = GetNullableString(reader, 5),
|
||||
Description = GetNullableString(reader, 6),
|
||||
Severity = GetNullableString(reader, 7),
|
||||
PublishedAt = GetNullableDateTimeOffset(reader, 8),
|
||||
ModifiedAt = GetNullableDateTimeOffset(reader, 9),
|
||||
WithdrawnAt = GetNullableDateTimeOffset(reader, 10),
|
||||
Provenance = reader.GetString(11),
|
||||
RawPayload = GetNullableString(reader, 12),
|
||||
CreatedAt = reader.GetFieldValue<DateTimeOffset>(13),
|
||||
UpdatedAt = reader.GetFieldValue<DateTimeOffset>(14)
|
||||
};
|
||||
}
|
||||
@@ -0,0 +1,75 @@
|
||||
using StellaOps.Concelier.Storage.Postgres.Models;
|
||||
|
||||
namespace StellaOps.Concelier.Storage.Postgres.Repositories;
|
||||
|
||||
/// <summary>
|
||||
/// Repository interface for advisory operations.
|
||||
/// </summary>
|
||||
public interface IAdvisoryRepository
|
||||
{
|
||||
/// <summary>
|
||||
/// Creates or updates an advisory (upsert by advisory_key).
|
||||
/// </summary>
|
||||
Task<AdvisoryEntity> UpsertAsync(AdvisoryEntity advisory, CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets an advisory by ID.
|
||||
/// </summary>
|
||||
Task<AdvisoryEntity?> GetByIdAsync(Guid id, CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets an advisory by key.
|
||||
/// </summary>
|
||||
Task<AdvisoryEntity?> GetByKeyAsync(string advisoryKey, CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets an advisory by primary vulnerability ID (CVE, GHSA, etc.).
|
||||
/// </summary>
|
||||
Task<AdvisoryEntity?> GetByVulnIdAsync(string vulnId, CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Searches advisories by full-text search.
|
||||
/// </summary>
|
||||
Task<IReadOnlyList<AdvisoryEntity>> SearchAsync(
|
||||
string query,
|
||||
string? severity = null,
|
||||
int limit = 50,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets advisories by severity.
|
||||
/// </summary>
|
||||
Task<IReadOnlyList<AdvisoryEntity>> GetBySeverityAsync(
|
||||
string severity,
|
||||
int limit = 100,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets advisories modified since a given time.
|
||||
/// </summary>
|
||||
Task<IReadOnlyList<AdvisoryEntity>> GetModifiedSinceAsync(
|
||||
DateTimeOffset since,
|
||||
int limit = 1000,
|
||||
CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Gets advisories by source.
|
||||
/// </summary>
|
||||
Task<IReadOnlyList<AdvisoryEntity>> GetBySourceAsync(
|
||||
Guid sourceId,
|
||||
int limit = 100,
|
||||
int offset = 0,
|
||||
CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Counts total advisories.
|
||||
/// </summary>
|
||||
Task<long> CountAsync(CancellationToken cancellationToken = default);
|
||||
|
||||
/// <summary>
|
||||
/// Counts advisories by severity.
|
||||
/// </summary>
|
||||
Task<IDictionary<string, long>> CountBySeverityAsync(CancellationToken cancellationToken = default);
|
||||
}
|
||||
@@ -0,0 +1,53 @@
|
||||
using Microsoft.Extensions.Configuration;
|
||||
using Microsoft.Extensions.DependencyInjection;
|
||||
using StellaOps.Concelier.Storage.Postgres.Repositories;
|
||||
using StellaOps.Infrastructure.Postgres;
|
||||
using StellaOps.Infrastructure.Postgres.Options;
|
||||
|
||||
namespace StellaOps.Concelier.Storage.Postgres;
|
||||
|
||||
/// <summary>
|
||||
/// Extension methods for configuring Concelier PostgreSQL storage services.
|
||||
/// </summary>
|
||||
public static class ServiceCollectionExtensions
|
||||
{
|
||||
/// <summary>
|
||||
/// Adds Concelier PostgreSQL storage services.
|
||||
/// </summary>
|
||||
/// <param name="services">Service collection.</param>
|
||||
/// <param name="configuration">Configuration root.</param>
|
||||
/// <param name="sectionName">Configuration section name for PostgreSQL options.</param>
|
||||
/// <returns>Service collection for chaining.</returns>
|
||||
public static IServiceCollection AddConcelierPostgresStorage(
|
||||
this IServiceCollection services,
|
||||
IConfiguration configuration,
|
||||
string sectionName = "Postgres:Concelier")
|
||||
{
|
||||
services.Configure<PostgresOptions>(sectionName, configuration.GetSection(sectionName));
|
||||
services.AddSingleton<ConcelierDataSource>();
|
||||
|
||||
// Register repositories
|
||||
services.AddScoped<IAdvisoryRepository, AdvisoryRepository>();
|
||||
|
||||
return services;
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Adds Concelier PostgreSQL storage services with explicit options.
|
||||
/// </summary>
|
||||
/// <param name="services">Service collection.</param>
|
||||
/// <param name="configureOptions">Options configuration action.</param>
|
||||
/// <returns>Service collection for chaining.</returns>
|
||||
public static IServiceCollection AddConcelierPostgresStorage(
|
||||
this IServiceCollection services,
|
||||
Action<PostgresOptions> configureOptions)
|
||||
{
|
||||
services.Configure(configureOptions);
|
||||
services.AddSingleton<ConcelierDataSource>();
|
||||
|
||||
// Register repositories
|
||||
services.AddScoped<IAdvisoryRepository, AdvisoryRepository>();
|
||||
|
||||
return services;
|
||||
}
|
||||
}
|
||||
@@ -0,0 +1,21 @@
|
||||
<?xml version="1.0" ?>
|
||||
<Project Sdk="Microsoft.NET.Sdk">
|
||||
|
||||
<PropertyGroup>
|
||||
<TargetFramework>net10.0</TargetFramework>
|
||||
<ImplicitUsings>enable</ImplicitUsings>
|
||||
<Nullable>enable</Nullable>
|
||||
<LangVersion>preview</LangVersion>
|
||||
<TreatWarningsAsErrors>true</TreatWarningsAsErrors>
|
||||
<RootNamespace>StellaOps.Concelier.Storage.Postgres</RootNamespace>
|
||||
</PropertyGroup>
|
||||
|
||||
<ItemGroup>
|
||||
<None Include="Migrations\**\*.sql" CopyToOutputDirectory="PreserveNewest" />
|
||||
</ItemGroup>
|
||||
|
||||
<ItemGroup>
|
||||
<ProjectReference Include="..\..\..\__Libraries\StellaOps.Infrastructure.Postgres\StellaOps.Infrastructure.Postgres.csproj" />
|
||||
</ItemGroup>
|
||||
|
||||
</Project>
|
||||
Reference in New Issue
Block a user