Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions migration/src/lib.rs
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,7 @@ mod m0001150_case_license_text_sbom_id_function;
mod m0001160_improve_expand_spdx_licenses_function;
mod m0001170_non_null_source_document_id;
mod m0001180_expand_spdx_licenses_with_mappings_function;
mod m0001190_optimize_product_advisory_query;

pub struct Migrator;

Expand Down Expand Up @@ -67,6 +68,7 @@ impl MigratorTrait for Migrator {
Box::new(m0001160_improve_expand_spdx_licenses_function::Migration),
Box::new(m0001170_non_null_source_document_id::Migration),
Box::new(m0001180_expand_spdx_licenses_with_mappings_function::Migration),
Box::new(m0001190_optimize_product_advisory_query::Migration),
]
}
}
Expand Down
48 changes: 48 additions & 0 deletions migration/src/m0001190_optimize_product_advisory_query.rs
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
use sea_orm_migration::prelude::*;

#[derive(DeriveMigrationName)]
pub struct Migration;

#[async_trait::async_trait]
impl MigrationTrait for Migration {
async fn up(&self, manager: &SchemaManager) -> Result<(), DbErr> {
// Index to optimize product_status.package lookups in the optimized query
// This supports the JOIN in product_status_matches_name CTE
manager
.create_index(
Index::create()
.table(ProductStatus::Table)
.name(Indexes::ProductStatusPackageIdx.to_string())
.col(ProductStatus::Package)
.to_owned(),
)
.await?;

Ok(())
}

async fn down(&self, manager: &SchemaManager) -> Result<(), DbErr> {
manager
.drop_index(
Index::drop()
.if_exists()
.table(ProductStatus::Table)
.name(Indexes::ProductStatusPackageIdx.to_string())
.to_owned(),
)
.await?;

Ok(())
}
}

#[derive(DeriveIden)]
pub enum Indexes {
ProductStatusPackageIdx,
}

#[derive(DeriveIden)]
pub enum ProductStatus {
Table,
Package,
}
134 changes: 109 additions & 25 deletions modules/fundamental/src/sbom/model/raw_sql.rs
Original file line number Diff line number Diff line change
Expand Up @@ -53,40 +53,124 @@ pub const CONTEXT_CPE_FILTER_SQL: &str = r#"
"#;

pub fn product_advisory_info_sql() -> String {
format!(
r#"
r#"
WITH
-- Pre-compute CPE context filter once instead of in WHERE clause
related_nodes AS (
SELECT DISTINCT right_node_id
FROM package_relates_to_package
WHERE sbom_id = $1
AND relationship = 13
),
sbom_cpes AS (
SELECT cpe_id, node_id
FROM sbom_package_cpe_ref
WHERE sbom_id = $1
AND node_id IN (SELECT right_node_id FROM related_nodes)
),
filtered_cpes AS (
SELECT cpe.*
FROM sbom_cpes spcr
JOIN cpe ON spcr.cpe_id = cpe.id
),
generalized_cpes AS (
SELECT *
FROM cpe
WHERE (edition IS NULL OR edition = '*')
AND (vendor, product, version) IN (
SELECT vendor, product, split_part(version, '.', 1)
FROM filtered_cpes
)
),
allowed_cpe_ids AS (
SELECT id FROM filtered_cpes
UNION
SELECT id FROM generalized_cpes
),

-- Pre-filter SBOM packages for this specific SBOM to avoid repeated scans
sbom_purls AS (
SELECT
qp.id as qualified_purl_id,
bp.name,
bp.namespace,
spr.sbom_id,
spr.node_id
FROM sbom_package_purl_ref spr
JOIN qualified_purl qp ON spr.qualified_purl_id = qp.id
JOIN versioned_purl vp ON qp.versioned_purl_id = vp.id
JOIN base_purl bp ON vp.base_purl_id = bp.id
WHERE spr.sbom_id = $1
),

-- Split OR condition into UNION to enable index usage
-- Match 1: Simple name equality (most common case)
product_status_matches_name AS (
SELECT DISTINCT
ps.id as product_status_id,
ps.advisory_id,
ps.vulnerability_id,
ps.status_id,
ps.context_cpe_id,
sp.qualified_purl_id,
sp.sbom_id,
sp.node_id
FROM product_status ps
JOIN sbom_purls sp ON ps.package = sp.name
WHERE (ps.context_cpe_id IS NULL
OR ps.context_cpe_id IN (SELECT id FROM allowed_cpe_ids)
OR NOT EXISTS (SELECT 1 FROM sbom_cpes LIMIT 1))
),

-- Match 2: Namespace/name concatenation (handles scoped packages like npm, maven)
product_status_matches_namespace AS (
SELECT DISTINCT
ps.id as product_status_id,
ps.advisory_id,
ps.vulnerability_id,
ps.status_id,
ps.context_cpe_id,
sp.qualified_purl_id,
sp.sbom_id,
sp.node_id
FROM product_status ps
JOIN sbom_purls sp ON ps.package = CONCAT(sp.namespace, '/', sp.name)
WHERE sp.namespace IS NOT NULL
AND (ps.context_cpe_id IS NULL
OR ps.context_cpe_id IN (SELECT id FROM allowed_cpe_ids)
OR NOT EXISTS (SELECT 1 FROM sbom_cpes LIMIT 1))
),

-- Union the two match types to eliminate OR in JOIN
all_matches AS (
SELECT * FROM product_status_matches_name
UNION
SELECT * FROM product_status_matches_namespace
)

-- Final query joins to get all required fields
SELECT DISTINCT
"advisory"."id" AS "advisory_id",
"advisory_vulnerability"."advisory_id" AS "av_advisory_id",
"advisory_vulnerability"."vulnerability_id" AS "av_vulnerability_id",
"vulnerability"."id" AS "vulnerability_id",
"qualified_purl"."id" AS "qualified_purl_id",
"sbom_package"."sbom_id" AS "sbom_id",
"sbom_package"."node_id" AS "node_id",
m.qualified_purl_id AS "qualified_purl_id",
m.sbom_id AS "sbom_id",
m.node_id AS "node_id",
"status"."id" AS "status_id",
"cpe"."id" AS "cpe_id",
"organization"."id" AS "organization_id"
FROM product_status
JOIN cpe ON product_status.context_cpe_id = cpe.id

-- now find matching purls in these statuses
JOIN base_purl ON product_status.package = base_purl.name OR product_status.package LIKE CONCAT(base_purl.namespace, '/', base_purl.name)
JOIN "versioned_purl" ON "versioned_purl"."base_purl_id" = "base_purl"."id"
JOIN "qualified_purl" ON "qualified_purl"."versioned_purl_id" = "versioned_purl"."id"
join sbom_package_purl_ref ON sbom_package_purl_ref.qualified_purl_id = qualified_purl.id AND sbom_package_purl_ref.sbom_id = $1
JOIN sbom_package on sbom_package.sbom_id = sbom_package_purl_ref.sbom_id AND sbom_package.node_id = sbom_package_purl_ref.node_id
JOIN sbom_node on sbom_node.sbom_id = sbom_package_purl_ref.sbom_id AND sbom_node.node_id = sbom_package_purl_ref.node_id

-- get basic status info
JOIN "status" ON "product_status"."status_id" = "status"."id"
JOIN "advisory" ON "product_status"."advisory_id" = "advisory"."id"
FROM all_matches m
JOIN sbom_package ON sbom_package.sbom_id = m.sbom_id AND sbom_package.node_id = m.node_id
JOIN sbom_node ON sbom_node.sbom_id = m.sbom_id AND sbom_node.node_id = m.node_id
JOIN "status" ON m.status_id = "status"."id"
JOIN "advisory" ON m.advisory_id = "advisory"."id"
LEFT JOIN "organization" ON "advisory"."issuer_id" = "organization"."id"
JOIN "advisory_vulnerability" ON "product_status"."advisory_id" = "advisory_vulnerability"."advisory_id"
AND "product_status"."vulnerability_id" = "advisory_vulnerability"."vulnerability_id"
JOIN "advisory_vulnerability" ON m.advisory_id = "advisory_vulnerability"."advisory_id"
AND m.vulnerability_id = "advisory_vulnerability"."vulnerability_id"
JOIN "vulnerability" ON "advisory_vulnerability"."vulnerability_id" = "vulnerability"."id"
WHERE
($2::text[] = ARRAY[]::text[] OR "status"."slug" = ANY($2::text[]))
AND {CONTEXT_CPE_FILTER_SQL}
LEFT JOIN "cpe" ON m.context_cpe_id = "cpe"."id"
WHERE ($2::text[] = ARRAY[]::text[] OR "status"."slug" = ANY($2::text[]))
"#
)
.to_string()
}