From 175cea7df445696796a7a7b3d3aa2c1dfd989b33 Mon Sep 17 00:00:00 2001 From: Quentin Machu Date: Sun, 4 Dec 2016 12:54:09 +0100 Subject: [PATCH] pgsql: Reduce cost of GetNotification by 3.4x By delaying the Layer join to the very end, we can cut the query costs from 540,836 to 219,477. Furthermore, by limiting the results early (in the CTE), the costs can be trimmed down to 159,298. See Pull Request for details. --- database/pgsql/queries.go | 32 +++++++++++++++----------------- 1 file changed, 15 insertions(+), 17 deletions(-) diff --git a/database/pgsql/queries.go b/database/pgsql/queries.go index 99dec448c5..255f9ddc82 100644 --- a/database/pgsql/queries.go +++ b/database/pgsql/queries.go @@ -211,23 +211,21 @@ const ( WHERE name = $1` searchNotificationLayerIntroducingVulnerability = ` - WITH subquery AS ( - SELECT l.ID, l.name - FROM Vulnerability_Affects_FeatureVersion vafv, FeatureVersion fv, Layer_diff_FeatureVersion ldfv, Layer l - WHERE l.id >= $2 - AND vafv.vulnerability_id = $1 - AND vafv.featureversion_id = fv.id - AND ldfv.featureversion_id = fv.id - AND ldfv.modification = 'add' - AND ldfv.layer_id = l.id - ORDER BY l.ID - ) - - SELECT * - FROM subquery - LIMIT $3; -` - + WITH LDFV AS ( + SELECT ldfv.layer_id + FROM Vulnerability_Affects_FeatureVersion vafv, FeatureVersion fv, Layer_diff_FeatureVersion ldfv + WHERE ldfv.layer_id >= $2 + AND vafv.vulnerability_id = $1 + AND vafv.featureversion_id = fv.id + AND ldfv.featureversion_id = fv.id + AND ldfv.modification = 'add' + ORDER BY ldfv.ID + LIMIT $3 + ) + SELECT l.id, l.name + FROM LDFV, Layer l + WHERE LDFV.layer_id = l.id` + // complex_test.go searchComplexTestFeatureVersionAffects = ` SELECT v.name