mirror of
https://github.com/Unleash/unleash.git
synced 2025-02-09 00:18:00 +01:00
feat: fix paging in sql by using common table expressions (#5343)
Optimizations: 1. Removed extra round trip to database to count environments 2. Removed extra round trip to database to count features Fixes: Currently, we were using a very optimistic query to set correct limit and offset. This breaks as soon we we join tags. ` query = query .select(selectColumns) .limit(limit * environmentCount) .offset(offset * environmentCount);` The solution was to use common table expressions, so we could count and rank features.
This commit is contained in:
parent
4e1040c849
commit
f3df3a31bf
@ -404,3 +404,27 @@ test('should sort features', async () => {
|
|||||||
total: 3,
|
total: 3,
|
||||||
});
|
});
|
||||||
});
|
});
|
||||||
|
test('should paginate correctly when using tags', async () => {
|
||||||
|
await app.createFeature('my_feature_a');
|
||||||
|
await app.createFeature('my_feature_b');
|
||||||
|
await app.createFeature('my_feature_c');
|
||||||
|
await app.createFeature('my_feature_d');
|
||||||
|
|
||||||
|
await app.addTag('my_feature_b', { type: 'simple', value: 'first_tag' });
|
||||||
|
await app.addTag('my_feature_b', { type: 'simple', value: 'second_tag' });
|
||||||
|
await app.addTag('my_feature_a', { type: 'simple', value: 'second_tag' });
|
||||||
|
await app.addTag('my_feature_c', { type: 'simple', value: 'second_tag' });
|
||||||
|
await app.addTag('my_feature_c', { type: 'simple', value: 'first_tag' });
|
||||||
|
|
||||||
|
const { body: secondPage, headers: secondHeaders } =
|
||||||
|
await searchFeaturesWithOffset({
|
||||||
|
query: 'feature',
|
||||||
|
offset: '2',
|
||||||
|
limit: '2',
|
||||||
|
});
|
||||||
|
|
||||||
|
expect(secondPage).toMatchObject({
|
||||||
|
features: [{ name: 'my_feature_c' }, { name: 'my_feature_d' }],
|
||||||
|
total: 4,
|
||||||
|
});
|
||||||
|
});
|
||||||
|
@ -541,207 +541,209 @@ class FeatureStrategiesStore implements IFeatureStrategiesStore {
|
|||||||
const validatedSortOrder =
|
const validatedSortOrder =
|
||||||
sortOrder === 'asc' || sortOrder === 'desc' ? sortOrder : 'asc';
|
sortOrder === 'asc' || sortOrder === 'desc' ? sortOrder : 'asc';
|
||||||
|
|
||||||
let environmentCount = 1;
|
const finalQuery = this.db
|
||||||
if (projectId) {
|
.with('ranked_features', (query) => {
|
||||||
const rows = await this.db('project_environments')
|
query.from('features');
|
||||||
.count('* as environmentCount')
|
if (projectId) {
|
||||||
.where('project_id', projectId);
|
query.where({ project: projectId });
|
||||||
environmentCount = Number(rows[0].environmentCount);
|
}
|
||||||
}
|
const hasQueryString = Boolean(queryString?.trim());
|
||||||
|
const hasHalfTag =
|
||||||
|
normalizedHalfTag && normalizedHalfTag.length > 0;
|
||||||
|
if (hasQueryString || hasHalfTag) {
|
||||||
|
const tagQuery = this.db
|
||||||
|
.from('feature_tag')
|
||||||
|
.select('feature_name');
|
||||||
|
// todo: we can run a cheaper query when no colon is detected
|
||||||
|
if (hasQueryString) {
|
||||||
|
tagQuery.whereRaw("(?? || ':' || ??) ILIKE ?", [
|
||||||
|
'tag_type',
|
||||||
|
'tag_value',
|
||||||
|
`%${queryString}%`,
|
||||||
|
]);
|
||||||
|
}
|
||||||
|
if (hasHalfTag) {
|
||||||
|
const tagParameters = normalizedHalfTag.map(
|
||||||
|
(tag) => `%${tag}%`,
|
||||||
|
);
|
||||||
|
const tagQueryParameters = normalizedHalfTag
|
||||||
|
.map(() => '?')
|
||||||
|
.join(',');
|
||||||
|
tagQuery
|
||||||
|
.orWhereRaw(
|
||||||
|
`(??) ILIKE ANY (ARRAY[${tagQueryParameters}])`,
|
||||||
|
['tag_type', ...tagParameters],
|
||||||
|
)
|
||||||
|
.orWhereRaw(
|
||||||
|
`(??) ILIKE ANY (ARRAY[${tagQueryParameters}])`,
|
||||||
|
['tag_value', ...tagParameters],
|
||||||
|
);
|
||||||
|
}
|
||||||
|
|
||||||
let query = this.db('features');
|
query.where((builder) => {
|
||||||
if (projectId) {
|
builder
|
||||||
query = query.where({ project: projectId });
|
.whereILike('features.name', `%${queryString}%`)
|
||||||
}
|
.orWhereIn('features.name', tagQuery);
|
||||||
const hasQueryString = Boolean(queryString?.trim());
|
});
|
||||||
const hasHalfTag = normalizedHalfTag && normalizedHalfTag.length > 0;
|
}
|
||||||
if (hasQueryString || hasHalfTag) {
|
if (normalizedFullTag && normalizedFullTag.length > 0) {
|
||||||
const tagQuery = this.db.from('feature_tag').select('feature_name');
|
const tagQuery = this.db
|
||||||
// todo: we can run a cheaper query when no colon is detected
|
.from('feature_tag')
|
||||||
if (hasQueryString) {
|
.select('feature_name')
|
||||||
tagQuery.whereRaw("(?? || ':' || ??) ILIKE ?", [
|
.whereIn(['tag_type', 'tag_value'], normalizedFullTag);
|
||||||
'tag_type',
|
query.whereIn('features.name', tagQuery);
|
||||||
'tag_value',
|
}
|
||||||
`%${queryString}%`,
|
if (type) {
|
||||||
]);
|
query.whereIn('features.type', type);
|
||||||
}
|
}
|
||||||
if (hasHalfTag) {
|
|
||||||
const tagParameters = normalizedHalfTag.map(
|
if (status && status.length > 0) {
|
||||||
(tag) => `%${tag}%`,
|
query.where((builder) => {
|
||||||
);
|
for (const [envName, envStatus] of status) {
|
||||||
const tagQueryParameters = normalizedHalfTag
|
builder.orWhere(function () {
|
||||||
.map(() => '?')
|
this.where(
|
||||||
.join(',');
|
'feature_environments.environment',
|
||||||
tagQuery
|
envName,
|
||||||
.orWhereRaw(
|
).andWhere(
|
||||||
`(??) ILIKE ANY (ARRAY[${tagQueryParameters}])`,
|
'feature_environments.enabled',
|
||||||
['tag_type', ...tagParameters],
|
envStatus === 'enabled' ? true : false,
|
||||||
|
);
|
||||||
|
});
|
||||||
|
}
|
||||||
|
});
|
||||||
|
}
|
||||||
|
|
||||||
|
query
|
||||||
|
.modify(FeatureToggleStore.filterByArchived, false)
|
||||||
|
.leftJoin(
|
||||||
|
'feature_environments',
|
||||||
|
'feature_environments.feature_name',
|
||||||
|
'features.name',
|
||||||
)
|
)
|
||||||
.orWhereRaw(
|
.leftJoin(
|
||||||
`(??) ILIKE ANY (ARRAY[${tagQueryParameters}])`,
|
'environments',
|
||||||
['tag_value', ...tagParameters],
|
'feature_environments.environment',
|
||||||
|
'environments.name',
|
||||||
|
)
|
||||||
|
.leftJoin(
|
||||||
|
'feature_tag as ft',
|
||||||
|
'ft.feature_name',
|
||||||
|
'features.name',
|
||||||
);
|
);
|
||||||
}
|
|
||||||
|
|
||||||
query = query.where((builder) => {
|
if (this.flagResolver.isEnabled('useLastSeenRefactor')) {
|
||||||
builder
|
query.leftJoin('last_seen_at_metrics', function () {
|
||||||
.whereILike('features.name', `%${queryString}%`)
|
this.on(
|
||||||
.orWhereIn('features.name', tagQuery);
|
'last_seen_at_metrics.environment',
|
||||||
});
|
'=',
|
||||||
}
|
'environments.name',
|
||||||
if (normalizedFullTag && normalizedFullTag.length > 0) {
|
).andOn(
|
||||||
const tagQuery = this.db
|
'last_seen_at_metrics.feature_name',
|
||||||
.from('feature_tag')
|
'=',
|
||||||
.select('feature_name')
|
'features.name',
|
||||||
.whereIn(['tag_type', 'tag_value'], normalizedFullTag);
|
|
||||||
query = query.whereIn('features.name', tagQuery);
|
|
||||||
}
|
|
||||||
if (type) {
|
|
||||||
query = query.whereIn('features.type', type);
|
|
||||||
}
|
|
||||||
|
|
||||||
if (status && status.length > 0) {
|
|
||||||
query = query.where((builder) => {
|
|
||||||
for (const [envName, envStatus] of status) {
|
|
||||||
builder.orWhere(function () {
|
|
||||||
this.where(
|
|
||||||
'feature_environments.environment',
|
|
||||||
envName,
|
|
||||||
).andWhere(
|
|
||||||
'feature_environments.enabled',
|
|
||||||
envStatus === 'enabled' ? true : false,
|
|
||||||
);
|
);
|
||||||
});
|
});
|
||||||
}
|
}
|
||||||
});
|
|
||||||
}
|
|
||||||
|
|
||||||
query = query
|
let selectColumns = [
|
||||||
.modify(FeatureToggleStore.filterByArchived, false)
|
'features.name as feature_name',
|
||||||
.leftJoin(
|
'features.description as description',
|
||||||
'feature_environments',
|
'features.type as type',
|
||||||
'feature_environments.feature_name',
|
'features.created_at as created_at',
|
||||||
'features.name',
|
'features.last_seen_at as last_seen_at',
|
||||||
|
'features.stale as stale',
|
||||||
|
'features.impression_data as impression_data',
|
||||||
|
'feature_environments.enabled as enabled',
|
||||||
|
'feature_environments.environment as environment',
|
||||||
|
'feature_environments.variants as variants',
|
||||||
|
'environments.type as environment_type',
|
||||||
|
'environments.sort_order as environment_sort_order',
|
||||||
|
'ft.tag_value as tag_value',
|
||||||
|
'ft.tag_type as tag_type',
|
||||||
|
] as (string | Raw<any> | Knex.QueryBuilder)[];
|
||||||
|
|
||||||
|
let lastSeenQuery = 'feature_environments.last_seen_at';
|
||||||
|
if (this.flagResolver.isEnabled('useLastSeenRefactor')) {
|
||||||
|
lastSeenQuery = 'last_seen_at_metrics.last_seen_at';
|
||||||
|
selectColumns.push(`${lastSeenQuery} as env_last_seen_at`);
|
||||||
|
}
|
||||||
|
|
||||||
|
if (userId) {
|
||||||
|
query.leftJoin(`favorite_features`, function () {
|
||||||
|
this.on(
|
||||||
|
'favorite_features.feature',
|
||||||
|
'features.name',
|
||||||
|
).andOnVal('favorite_features.user_id', '=', userId);
|
||||||
|
});
|
||||||
|
selectColumns = [
|
||||||
|
...selectColumns,
|
||||||
|
this.db.raw(
|
||||||
|
'favorite_features.feature is not null as favorite',
|
||||||
|
),
|
||||||
|
];
|
||||||
|
}
|
||||||
|
|
||||||
|
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',
|
||||||
|
),
|
||||||
|
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',
|
||||||
|
),
|
||||||
|
];
|
||||||
|
|
||||||
|
const sortByMapping = {
|
||||||
|
name: 'features.name',
|
||||||
|
type: 'features.type',
|
||||||
|
lastSeenAt: lastSeenQuery,
|
||||||
|
};
|
||||||
|
|
||||||
|
let rankingSql = 'order by ';
|
||||||
|
if (favoritesFirst) {
|
||||||
|
rankingSql +=
|
||||||
|
'favorite_features.feature is not null desc, ';
|
||||||
|
}
|
||||||
|
|
||||||
|
if (sortBy.startsWith('environment:')) {
|
||||||
|
const [, envName] = sortBy.split(':');
|
||||||
|
rankingSql += this.db
|
||||||
|
.raw(
|
||||||
|
`CASE WHEN feature_environments.environment = ? THEN feature_environments.enabled ELSE NULL END ${validatedSortOrder} NULLS LAST, features.created_at asc`,
|
||||||
|
[envName],
|
||||||
|
)
|
||||||
|
.toString();
|
||||||
|
} else if (sortByMapping[sortBy]) {
|
||||||
|
rankingSql += `${this.db
|
||||||
|
.raw(`?? ${validatedSortOrder}`, [
|
||||||
|
sortByMapping[sortBy],
|
||||||
|
])
|
||||||
|
.toString()}, features.created_at asc`;
|
||||||
|
} else {
|
||||||
|
rankingSql += `features.created_at ${validatedSortOrder}`;
|
||||||
|
}
|
||||||
|
|
||||||
|
query
|
||||||
|
.select(selectColumns)
|
||||||
|
.denseRank('rank', this.db.raw(rankingSql));
|
||||||
|
})
|
||||||
|
.with(
|
||||||
|
'total_features',
|
||||||
|
this.db.raw('select max(rank) as total from ranked_features'),
|
||||||
)
|
)
|
||||||
.leftJoin(
|
.select('*')
|
||||||
'environments',
|
.from('ranked_features')
|
||||||
'feature_environments.environment',
|
.joinRaw('CROSS JOIN total_features')
|
||||||
'environments.name',
|
.whereBetween('rank', [offset + 1, offset + limit]);
|
||||||
)
|
|
||||||
.leftJoin('feature_tag as ft', 'ft.feature_name', 'features.name');
|
|
||||||
|
|
||||||
const countQuery = query.clone();
|
const rows = await finalQuery;
|
||||||
|
|
||||||
if (this.flagResolver.isEnabled('useLastSeenRefactor')) {
|
|
||||||
query.leftJoin('last_seen_at_metrics', function () {
|
|
||||||
this.on(
|
|
||||||
'last_seen_at_metrics.environment',
|
|
||||||
'=',
|
|
||||||
'environments.name',
|
|
||||||
).andOn(
|
|
||||||
'last_seen_at_metrics.feature_name',
|
|
||||||
'=',
|
|
||||||
'features.name',
|
|
||||||
);
|
|
||||||
});
|
|
||||||
}
|
|
||||||
|
|
||||||
let selectColumns = [
|
|
||||||
'features.name as feature_name',
|
|
||||||
'features.description as description',
|
|
||||||
'features.type as type',
|
|
||||||
'features.created_at as created_at',
|
|
||||||
'features.last_seen_at as last_seen_at',
|
|
||||||
'features.stale as stale',
|
|
||||||
'features.impression_data as impression_data',
|
|
||||||
'feature_environments.enabled as enabled',
|
|
||||||
'feature_environments.environment as environment',
|
|
||||||
'feature_environments.variants as variants',
|
|
||||||
'environments.type as environment_type',
|
|
||||||
'environments.sort_order as environment_sort_order',
|
|
||||||
'ft.tag_value as tag_value',
|
|
||||||
'ft.tag_type as tag_type',
|
|
||||||
] as (string | Raw<any> | Knex.QueryBuilder)[];
|
|
||||||
|
|
||||||
if (this.flagResolver.isEnabled('useLastSeenRefactor')) {
|
|
||||||
selectColumns.push(
|
|
||||||
'last_seen_at_metrics.last_seen_at as env_last_seen_at',
|
|
||||||
);
|
|
||||||
} else {
|
|
||||||
selectColumns.push(
|
|
||||||
'feature_environments.last_seen_at as env_last_seen_at',
|
|
||||||
);
|
|
||||||
}
|
|
||||||
|
|
||||||
if (userId) {
|
|
||||||
query = query.leftJoin(`favorite_features`, function () {
|
|
||||||
this.on('favorite_features.feature', 'features.name').andOnVal(
|
|
||||||
'favorite_features.user_id',
|
|
||||||
'=',
|
|
||||||
userId,
|
|
||||||
);
|
|
||||||
});
|
|
||||||
selectColumns = [
|
|
||||||
...selectColumns,
|
|
||||||
this.db.raw(
|
|
||||||
'favorite_features.feature is not null as favorite',
|
|
||||||
),
|
|
||||||
];
|
|
||||||
}
|
|
||||||
|
|
||||||
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',
|
|
||||||
),
|
|
||||||
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',
|
|
||||||
),
|
|
||||||
];
|
|
||||||
|
|
||||||
const sortByMapping = {
|
|
||||||
name: 'feature_name',
|
|
||||||
type: 'type',
|
|
||||||
lastSeenAt: 'env_last_seen_at',
|
|
||||||
};
|
|
||||||
|
|
||||||
if (favoritesFirst) {
|
|
||||||
query = query.orderBy('favorite', 'desc');
|
|
||||||
}
|
|
||||||
|
|
||||||
if (sortBy.startsWith('environment:')) {
|
|
||||||
const [, envName] = sortBy.split(':');
|
|
||||||
query = query
|
|
||||||
.orderByRaw(
|
|
||||||
`CASE WHEN feature_environments.environment = ? THEN feature_environments.enabled ELSE NULL END ${validatedSortOrder} NULLS LAST`,
|
|
||||||
[envName],
|
|
||||||
)
|
|
||||||
.orderBy('created_at', 'asc');
|
|
||||||
} else if (sortByMapping[sortBy]) {
|
|
||||||
query = query
|
|
||||||
.orderBy(sortByMapping[sortBy], validatedSortOrder)
|
|
||||||
.orderBy('created_at', 'asc');
|
|
||||||
} else {
|
|
||||||
query = query.orderBy('created_at', validatedSortOrder);
|
|
||||||
}
|
|
||||||
|
|
||||||
const total = await countQuery
|
|
||||||
.countDistinct({ total: 'features.name' })
|
|
||||||
.first();
|
|
||||||
|
|
||||||
query = query
|
|
||||||
.select(selectColumns)
|
|
||||||
.limit(limit * environmentCount)
|
|
||||||
.offset(offset * environmentCount);
|
|
||||||
|
|
||||||
const rows = await query;
|
|
||||||
|
|
||||||
if (rows.length > 0) {
|
if (rows.length > 0) {
|
||||||
const overview = this.getFeatureOverviewData(rows);
|
const overview = this.getFeatureOverviewData(rows);
|
||||||
const features = sortEnvironments(overview);
|
const features = sortEnvironments(overview);
|
||||||
return {
|
return {
|
||||||
features,
|
features,
|
||||||
total: Number(total?.total) || 0,
|
total: Number(rows[0].total) || 0,
|
||||||
};
|
};
|
||||||
}
|
}
|
||||||
return {
|
return {
|
||||||
|
Loading…
Reference in New Issue
Block a user