From b9f43f5ba0759f993f28d1ba79a39a8ff7ecad55 Mon Sep 17 00:00:00 2001 From: Jaanus Sellin Date: Thu, 13 Jun 2024 13:11:47 +0300 Subject: [PATCH] feat: optimize search store by removing inline EXISTS (#7385) Instead of running exists on every row, we are joining the exists, which runs the query only once. This decreased load time on my huge dataset from 2000ms to 200ms. Also added tests that values still come through as expected. --- .../feature-search/feature-search-store.ts | 53 +++++++++++++++++-- .../feature-search/feature.search.e2e.test.ts | 17 ++++++ 2 files changed, 67 insertions(+), 3 deletions(-) diff --git a/src/lib/features/feature-search/feature-search-store.ts b/src/lib/features/feature-search/feature-search-store.ts index e2cb15d0bf..5dd2dcf33a 100644 --- a/src/lib/features/feature-search/feature-search-store.ts +++ b/src/lib/features/feature-search/feature-search-store.ts @@ -86,7 +86,10 @@ class FeatureSearchStore implements IFeatureSearchStore { .distinctOn('stage_feature') .orderBy([ 'stage_feature', - { column: 'entered_stage_at', order: 'desc' }, + { + column: 'entered_stage_at', + order: 'desc', + }, ]); } @@ -162,10 +165,10 @@ class FeatureSearchStore implements IFeatureSearchStore { selectColumns = [ ...selectColumns, this.db.raw( - 'EXISTS (SELECT 1 FROM feature_strategies WHERE feature_strategies.feature_name = features.name AND feature_strategies.environment = feature_environments.environment) as has_strategies', + 'has_strategies.feature_name IS NOT NULL AS has_strategies', ), this.db.raw( - 'EXISTS (SELECT 1 FROM feature_strategies WHERE feature_strategies.feature_name = features.name AND feature_strategies.environment = feature_environments.environment AND (feature_strategies.disabled IS NULL OR feature_strategies.disabled = false)) as has_enabled_strategies', + 'enabled_strategies.feature_name IS NOT NULL AS has_enabled_strategies', ), this.db.raw(`CASE WHEN dependent_features.parent = features.name THEN 'parent' @@ -245,6 +248,8 @@ class FeatureSearchStore implements IFeatureSearchStore { 'features.created_by_user_id', ); + this.applyStrategiesByEnvironment(query); + query.leftJoin('last_seen_at_metrics', function () { this.on( 'last_seen_at_metrics.environment', @@ -351,6 +356,48 @@ class FeatureSearchStore implements IFeatureSearchStore { }; } + private applyStrategiesByEnvironment(queryBuilder: Knex.QueryBuilder) { + queryBuilder + .leftJoin( + this.db + .select('feature_name', 'environment') + .from('feature_strategies') + .where(function () { + this.whereNull('disabled').orWhere('disabled', false); + }) + .as('enabled_strategies'), + function () { + this.on( + 'enabled_strategies.feature_name', + '=', + 'features.name', + ).andOn( + 'enabled_strategies.environment', + '=', + 'feature_environments.environment', + ); + }, + ) + .leftJoin( + this.db + .select('feature_name', 'environment') + .from('feature_strategies') + .groupBy('feature_name', 'environment') + .as('has_strategies'), + function () { + this.on( + 'has_strategies.feature_name', + '=', + 'features.name', + ).andOn( + 'has_strategies.environment', + '=', + 'feature_environments.environment', + ); + }, + ); + } + private buildRankingSql( favoritesFirst: undefined | boolean, sortBy: string, diff --git a/src/lib/features/feature-search/feature.search.e2e.test.ts b/src/lib/features/feature-search/feature.search.e2e.test.ts index 2a71e19237..f220182320 100644 --- a/src/lib/features/feature-search/feature.search.e2e.test.ts +++ b/src/lib/features/feature-search/feature.search.e2e.test.ts @@ -776,6 +776,23 @@ test('should return segments in payload with no duplicates/nulls', async () => { { name: 'my_feature_a', segments: [mySegment.name], + environments: [ + { + name: 'default', + hasStrategies: true, + hasEnabledStrategies: true, + }, + { + name: 'development', + hasStrategies: true, + hasEnabledStrategies: true, + }, + { + name: 'production', + hasStrategies: false, + hasEnabledStrategies: false, + }, + ], }, ], });