Skip to content

Commit

Permalink
Sort most dangerous vulnerabilities by score and severity level
Browse files Browse the repository at this point in the history
  Check it is referred by a scan_report
  Add index to report_vulnerability_record to improve performance
  Fixes #19014 #19028

Signed-off-by: stonezdj <[email protected]>
  • Loading branch information
stonezdj committed Aug 4, 2023
1 parent 854e029 commit b45b7d1
Show file tree
Hide file tree
Showing 2 changed files with 24 additions and 6 deletions.
3 changes: 3 additions & 0 deletions make/migrations/postgresql/0120_2.9.0_schema.up.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,9 @@ BEGIN
END IF;
END $$;

/* to improve the query of dangerousCVESQL it requires to query with vuln_record_id */
CREATE INDEX IF NOT EXISTS idx_report_vulnerability_record_vuln_record_id ON report_vulnerability_record (vuln_record_id);

CREATE INDEX IF NOT EXISTS idx_vulnerability_record_cvss_score_v3 ON vulnerability_record (cvss_score_v3);
CREATE INDEX IF NOT EXISTS idx_vulnerability_registration_uuid ON vulnerability_record (registration_uuid);
CREATE INDEX IF NOT EXISTS idx_vulnerability_record_cve_id ON vulnerability_record (cve_id);
Expand Down
27 changes: 21 additions & 6 deletions src/pkg/securityhub/dao/security.go
Original file line number Diff line number Diff line change
Expand Up @@ -53,12 +53,27 @@ from artifact
where exists (select 1 from scan_report s where artifact.digest = s.digest and s.registration_uuid = ?) `

// sql to query the dangerous CVEs
dangerousCVESQL = `select vr.*
from vulnerability_record vr
where vr.cvss_score_v3 is not null
and vr.registration_uuid = ?
order by vr.cvss_score_v3 desc
limit 5`
// sort the CVEs by CVSS score and severity level, make sure it is referred by a report
dangerousCVESQL = `SELECT vr.id,
vr.cve_id,
vr.package,
vr.cvss_score_v3,
vr.description,
vr.fixed_version,
vr.severity,
CASE vr.severity
WHEN 'Critical' THEN 5
WHEN 'High' THEN 4
WHEN 'Medium' THEN 3
WHEN 'Low' THEN 2
WHEN 'None' THEN 1
WHEN 'Unknown' THEN 0 END AS severity_level
FROM vulnerability_record vr
WHERE EXISTS (SELECT 1 FROM report_vulnerability_record WHERE vuln_record_id = vr.id)
AND vr.cvss_score_v3 IS NOT NULL
and vr.registration_uuid = ?
ORDER BY vr.cvss_score_v3 DESC, severity_level DESC
LIMIT 5`

// sql to query vulnerabilities
vulnerabilitySQL = `select vr.cve_id, vr.cvss_score_v3, vr.package, a.repository_name, a.id artifact_id, a.digest, vr.package, vr.package_version, vr.severity, vr.fixed_version, vr.description, vr.urls, a.project_id
Expand Down

0 comments on commit b45b7d1

Please sign in to comment.