diff --git a/make/migrations/postgresql/0120_2.9.0_schema.up.sql b/make/migrations/postgresql/0120_2.9.0_schema.up.sql index 19c4a5c3d..d69ace2eb 100644 --- a/make/migrations/postgresql/0120_2.9.0_schema.up.sql +++ b/make/migrations/postgresql/0120_2.9.0_schema.up.sql @@ -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); diff --git a/src/pkg/securityhub/dao/security.go b/src/pkg/securityhub/dao/security.go index c38839643..20495a04d 100644 --- a/src/pkg/securityhub/dao/security.go +++ b/src/pkg/securityhub/dao/security.go @@ -79,12 +79,27 @@ WHERE EXISTS (SELECT 1 WHERE s.digest = a.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 diff --git a/src/pkg/securityhub/dao/security_test.go b/src/pkg/securityhub/dao/security_test.go index 6b792196d..328b59520 100644 --- a/src/pkg/securityhub/dao/security_test.go +++ b/src/pkg/securityhub/dao/security_test.go @@ -70,8 +70,8 @@ values (1003, 1, 'library/hello-world', 'digest1003', 'IMAGE', '2023-06-02 09:16 INSERT INTO vulnerability_record(cve_id, registration_uuid, cvss_score_v3, package) VALUES ('CVE-2021-21345', 'uuid2', 9.9, 'com.thoughtworks.xstream:xstream'); INSERT INTO vulnerability_record(cve_id, registration_uuid, cvss_score_v3, package) VALUES ('CVE-2016-1585', 'uuid2', 9.8, 'libapparmor1'); INSERT INTO vulnerability_record(cve_id, registration_uuid, cvss_score_v3, package) VALUES ('CVE-2023-0950', 'uuid2', 9.8, 'ure'); - INSERT INTO vulnerability_record(cve_id, registration_uuid, cvss_score_v3, package) VALUES ('CVE-2022-47629', 'uuid2', 9.8, 'libksba8'); - `, + INSERT INTO vulnerability_record(cve_id, registration_uuid, cvss_score_v3, package) VALUES ('CVE-2022-47629', 'uuid2', 9.8, 'libksba8');`, + `INSERT INTO report_vulnerability_record(report_uuid, vuln_record_id) select 'uuid', id vuln_record_id from vulnerability_record where cve_id in ('CVE-2021-44228', 'CVE-2021-21345', 'CVE-2016-1585', 'CVE-2023-0950', 'CVE-2022-47629')`, }) } @@ -86,6 +86,7 @@ func (suite *SecurityDaoTestSuite) TearDownTest() { `delete from scanner_registration where uuid='uuid2'`, `delete from vulnerability_record where cve_id='2023-4567-12345'`, `delete from report_vulnerability_record where report_uuid='ruuid'`, + `delete from report_vulnerability_record where report_uuid='uuid'`, `delete from vulnerability_record where registration_uuid ='uuid2'`, `delete from tag where name='tag_test'`, })