Commit d83d9ec3df6e0a1fc87520a53fd7bc4deff87d54
1 parent
112b9250
Fix for sort order in search by attributes or telemetry
Showing
5 changed files
with
66 additions
and
31 deletions
... | ... | @@ -86,6 +86,7 @@ BEGIN |
86 | 86 | DROP INDEX IF EXISTS idx_asset_customer_id; |
87 | 87 | DROP INDEX IF EXISTS idx_asset_customer_id_and_type; |
88 | 88 | DROP INDEX IF EXISTS idx_asset_type; |
89 | + DROP INDEX IF EXISTS idx_attribute_kv_by_key_and_last_update_ts; | |
89 | 90 | END; |
90 | 91 | $$; |
91 | 92 | |
... | ... | @@ -105,6 +106,7 @@ BEGIN |
105 | 106 | CREATE INDEX IF NOT EXISTS idx_asset_customer_id ON asset(tenant_id, customer_id); |
106 | 107 | CREATE INDEX IF NOT EXISTS idx_asset_customer_id_and_type ON asset(tenant_id, customer_id, type); |
107 | 108 | CREATE INDEX IF NOT EXISTS idx_asset_type ON asset(tenant_id, type); |
109 | + CREATE INDEX IF NOT EXISTS idx_attribute_kv_by_key_and_last_update_ts ON attribute_kv(entity_id, attribute_key, last_update_ts desc); | |
108 | 110 | END; |
109 | 111 | $$; |
110 | 112 | ... | ... |
... | ... | @@ -39,6 +39,7 @@ import org.thingsboard.server.common.data.query.EntityDataQuery; |
39 | 39 | import org.thingsboard.server.common.data.query.EntityDataSortOrder; |
40 | 40 | import org.thingsboard.server.common.data.query.EntityFilter; |
41 | 41 | import org.thingsboard.server.common.data.query.EntityFilterType; |
42 | +import org.thingsboard.server.common.data.query.EntityKeyType; | |
42 | 43 | import org.thingsboard.server.common.data.query.EntityListFilter; |
43 | 44 | import org.thingsboard.server.common.data.query.EntityNameFilter; |
44 | 45 | import org.thingsboard.server.common.data.query.EntitySearchQueryFilter; |
... | ... | @@ -265,7 +266,8 @@ public class DefaultEntityQueryRepository implements EntityQueryRepository { |
265 | 266 | |
266 | 267 | |
267 | 268 | String entityWhereClause = DefaultEntityQueryRepository.this.buildEntityWhere(ctx, query.getEntityFilter(), entityFieldsFiltersMapping); |
268 | - String latestJoins = EntityKeyMapping.buildLatestJoins(ctx, query.getEntityFilter(), entityType, allLatestMappings); | |
269 | + String latestJoinsCnt = EntityKeyMapping.buildLatestJoins(ctx, query.getEntityFilter(), entityType, allLatestMappings, true); | |
270 | + String latestJoinsData = EntityKeyMapping.buildLatestJoins(ctx, query.getEntityFilter(), entityType, allLatestMappings, false); | |
269 | 271 | String whereClause = DefaultEntityQueryRepository.this.buildWhere(ctx, latestFiltersMapping, query.getEntityFilter().getType()); |
270 | 272 | String textSearchQuery = DefaultEntityQueryRepository.this.buildTextSearchQuery(ctx, selectionMapping, pageLink.getTextSearch()); |
271 | 273 | String entityFieldsSelection = EntityKeyMapping.buildSelections(entityFieldsSelectionMapping, query.getEntityFilter().getType(), entityType); |
... | ... | @@ -286,29 +288,44 @@ public class DefaultEntityQueryRepository implements EntityQueryRepository { |
286 | 288 | topSelection = topSelection + ", " + latestSelection; |
287 | 289 | } |
288 | 290 | |
289 | - String fromClause = String.format("from (select %s from (select %s from %s e where %s) entities %s %s) result %s", | |
291 | + String fromClauseCount = String.format("from (select %s from (select %s from %s e where %s) entities %s %s) result %s", | |
292 | + "entities.*", | |
293 | + entityFieldsSelection, | |
294 | + addEntityTableQuery(ctx, query.getEntityFilter()), | |
295 | + entityWhereClause, | |
296 | + latestJoinsCnt, | |
297 | + whereClause, | |
298 | + textSearchQuery); | |
299 | + | |
300 | + String fromClauseData = String.format("from (select %s from (select %s from %s e where %s) entities %s %s) result %s", | |
290 | 301 | topSelection, |
291 | 302 | entityFieldsSelection, |
292 | 303 | addEntityTableQuery(ctx, query.getEntityFilter()), |
293 | 304 | entityWhereClause, |
294 | - latestJoins, | |
305 | + latestJoinsData, | |
295 | 306 | whereClause, |
296 | 307 | textSearchQuery); |
297 | 308 | |
298 | - int totalElements = jdbcTemplate.queryForObject(String.format("select count(*) %s", fromClause), ctx, Integer.class); | |
309 | + if (!StringUtils.isEmpty(pageLink.getTextSearch())) { | |
310 | + //Unfortunately, we need to sacrifice performance in case of full text search, because it is applied to all joined records. | |
311 | + fromClauseCount = fromClauseData; | |
312 | + } | |
313 | + String countQuery = String.format("select count(id) %s", fromClauseCount); | |
314 | + int totalElements = jdbcTemplate.queryForObject(countQuery, ctx, Integer.class); | |
299 | 315 | |
300 | - String dataQuery = String.format("select * %s", fromClause); | |
316 | + String dataQuery = String.format("select * %s", fromClauseData); | |
301 | 317 | |
302 | 318 | EntityDataSortOrder sortOrder = pageLink.getSortOrder(); |
303 | 319 | if (sortOrder != null) { |
304 | 320 | Optional<EntityKeyMapping> sortOrderMappingOpt = mappings.stream().filter(EntityKeyMapping::isSortOrder).findFirst(); |
305 | 321 | if (sortOrderMappingOpt.isPresent()) { |
306 | 322 | EntityKeyMapping sortOrderMapping = sortOrderMappingOpt.get(); |
307 | - dataQuery = String.format("%s order by %s", dataQuery, sortOrderMapping.getValueAlias()); | |
308 | - if (sortOrder.getDirection() == EntityDataSortOrder.Direction.ASC) { | |
309 | - dataQuery += " asc"; | |
323 | + String direction = sortOrder.getDirection() == EntityDataSortOrder.Direction.ASC ? "asc" : "desc"; | |
324 | + if (sortOrderMapping.getEntityKey().getType() == EntityKeyType.ENTITY_FIELD) { | |
325 | + dataQuery = String.format("%s order by %s %s", dataQuery, sortOrderMapping.getValueAlias(), direction); | |
310 | 326 | } else { |
311 | - dataQuery += " desc"; | |
327 | + dataQuery = String.format("%s order by %s %s, %s %s", dataQuery, | |
328 | + sortOrderMapping.getSortOrderNumAlias(), direction, sortOrderMapping.getSortOrderStrAlias(), direction); | |
312 | 329 | } |
313 | 330 | } |
314 | 331 | } | ... | ... |
... | ... | @@ -270,9 +270,10 @@ public class EntityKeyMapping { |
270 | 270 | Collectors.joining(", ")); |
271 | 271 | } |
272 | 272 | |
273 | - public static String buildLatestJoins(QueryContext ctx, EntityFilter entityFilter, EntityType entityType, List<EntityKeyMapping> latestMappings) { | |
274 | - return latestMappings.stream().map(mapping -> mapping.toLatestJoin(ctx, entityFilter, entityType)).collect( | |
275 | - Collectors.joining(" ")); | |
273 | + public static String buildLatestJoins(QueryContext ctx, EntityFilter entityFilter, EntityType entityType, List<EntityKeyMapping> latestMappings, boolean countQuery) { | |
274 | + return latestMappings.stream().filter(mapping -> !countQuery || mapping.hasFilter()) | |
275 | + .map(mapping -> mapping.toLatestJoin(ctx, entityFilter, entityType)).collect( | |
276 | + Collectors.joining(" ")); | |
276 | 277 | } |
277 | 278 | |
278 | 279 | public static String buildQuery(QueryContext ctx, List<EntityKeyMapping> mappings, EntityFilterType filterType) { |
... | ... | @@ -363,19 +364,14 @@ public class EntityKeyMapping { |
363 | 364 | } |
364 | 365 | |
365 | 366 | private String buildAttributeSelection() { |
366 | - String attrValAlias = getValueAlias(); | |
367 | - String attrTsAlias = getTsAlias(); | |
368 | - String attrValSelection = | |
369 | - String.format("(coalesce(cast(%s.bool_v as varchar), '') || " + | |
370 | - "coalesce(%s.str_v, '') || " + | |
371 | - "coalesce(cast(%s.long_v as varchar), '') || " + | |
372 | - "coalesce(cast(%s.dbl_v as varchar), '') || " + | |
373 | - "coalesce(cast(%s.json_v as varchar), '')) as %s", alias, alias, alias, alias, alias, attrValAlias); | |
374 | - String attrTsSelection = String.format("%s.last_update_ts as %s", alias, attrTsAlias); | |
375 | - return String.join(", ", attrValSelection, attrTsSelection); | |
367 | + return buildTimeSeriesOrAttrSelection(true); | |
376 | 368 | } |
377 | 369 | |
378 | 370 | private String buildTimeSeriesSelection() { |
371 | + return buildTimeSeriesOrAttrSelection(false); | |
372 | + } | |
373 | + | |
374 | + private String buildTimeSeriesOrAttrSelection(boolean attr) { | |
379 | 375 | String attrValAlias = getValueAlias(); |
380 | 376 | String attrTsAlias = getTsAlias(); |
381 | 377 | String attrValSelection = |
... | ... | @@ -384,8 +380,25 @@ public class EntityKeyMapping { |
384 | 380 | "coalesce(cast(%s.long_v as varchar), '') || " + |
385 | 381 | "coalesce(cast(%s.dbl_v as varchar), '') || " + |
386 | 382 | "coalesce(cast(%s.json_v as varchar), '')) as %s", alias, alias, alias, alias, alias, attrValAlias); |
387 | - String attrTsSelection = String.format("%s.ts as %s", alias, attrTsAlias); | |
388 | - return String.join(", ", attrValSelection, attrTsSelection); | |
383 | + String attrTsSelection = String.format("%s.%s as %s", alias, attr ? "last_update_ts" : "ts", attrTsAlias); | |
384 | + if (this.isSortOrder) { | |
385 | + String attrNumAlias = getSortOrderNumAlias(); | |
386 | + String attrVarcharAlias = getSortOrderStrAlias(); | |
387 | + String attrSortOrderSelection = | |
388 | + String.format("coalesce(%s.dbl_v, cast(%s.long_v as double precision), (case when %s.bool_v then 1 else 0 end)) %s," + | |
389 | + "coalesce(%s.str_v, cast(%s.json_v as varchar), '') %s", alias, alias, alias, attrNumAlias, alias, alias, attrVarcharAlias); | |
390 | + return String.join(", ", attrValSelection, attrTsSelection, attrSortOrderSelection); | |
391 | + } else { | |
392 | + return String.join(", ", attrValSelection, attrTsSelection); | |
393 | + } | |
394 | + } | |
395 | + | |
396 | + public String getSortOrderStrAlias() { | |
397 | + return getValueAlias() + "_so_varchar"; | |
398 | + } | |
399 | + | |
400 | + public String getSortOrderNumAlias() { | |
401 | + return getValueAlias() + "_so_num"; | |
389 | 402 | } |
390 | 403 | |
391 | 404 | private String buildKeyQuery(QueryContext ctx, String alias, KeyFilter keyFilter, |
... | ... | @@ -425,11 +438,11 @@ public class EntityKeyMapping { |
425 | 438 | if (predicate.getType().equals(FilterPredicateType.NUMERIC)) { |
426 | 439 | return this.buildNumericPredicateQuery(ctx, field, (NumericFilterPredicate) predicate); |
427 | 440 | } else if (predicate.getType().equals(FilterPredicateType.STRING)) { |
428 | - if (key.getKey().equals("entityType") && !filterType.equals(EntityFilterType.RELATIONS_QUERY)){ | |
441 | + if (key.getKey().equals("entityType") && !filterType.equals(EntityFilterType.RELATIONS_QUERY)) { | |
429 | 442 | field = ctx.getEntityType().toString(); |
430 | 443 | return this.buildStringPredicateQuery(ctx, field, (StringFilterPredicate) predicate) |
431 | 444 | .replace("lower(" + field, "lower('" + field + "'") |
432 | - .replace(field + " ","'" + field + "' "); | |
445 | + .replace(field + " ", "'" + field + "' "); | |
433 | 446 | } else { |
434 | 447 | return this.buildStringPredicateQuery(ctx, field, (StringFilterPredicate) predicate); |
435 | 448 | } |
... | ... | @@ -481,13 +494,13 @@ public class EntityKeyMapping { |
481 | 494 | stringOperationQuery = String.format("%s like :%s) or (%s is null and :%s = '%%')", operationField, paramName, operationField, paramName); |
482 | 495 | break; |
483 | 496 | case CONTAINS: |
484 | - if (value.length()>0) { | |
497 | + if (value.length() > 0) { | |
485 | 498 | value = "%" + value + "%"; |
486 | 499 | } |
487 | 500 | stringOperationQuery = String.format("%s like :%s) or (%s is null and :%s = '')", operationField, paramName, operationField, paramName); |
488 | 501 | break; |
489 | 502 | case NOT_CONTAINS: |
490 | - if (value.length()>0) { | |
503 | + if (value.length() > 0) { | |
491 | 504 | value = "%" + value + "%"; |
492 | 505 | } |
493 | 506 | stringOperationQuery = String.format("%s not like :%s) or (%s is null and :%s != '')", operationField, paramName, operationField, paramName); | ... | ... |
... | ... | @@ -41,8 +41,9 @@ public class QueryContext implements SqlParameterSource { |
41 | 41 | } |
42 | 42 | |
43 | 43 | void addParameter(String name, Object value, int type, String typeName) { |
44 | - Parameter existing = params.put(name, new Parameter(value, type, typeName)); | |
45 | - if (existing != null) { | |
44 | + Parameter newParam = new Parameter(value, type, typeName); | |
45 | + Parameter oldParam = params.put(name, newParam); | |
46 | + if (oldParam != null && !oldParam.value.equals(newParam.value)) { | |
46 | 47 | throw new RuntimeException("Parameter with name: " + name + " was already registered!"); |
47 | 48 | } |
48 | 49 | } | ... | ... |
... | ... | @@ -36,4 +36,6 @@ CREATE INDEX IF NOT EXISTS idx_asset_customer_id ON asset(tenant_id, customer_id |
36 | 36 | |
37 | 37 | CREATE INDEX IF NOT EXISTS idx_asset_customer_id_and_type ON asset(tenant_id, customer_id, type); |
38 | 38 | |
39 | -CREATE INDEX IF NOT EXISTS idx_asset_type ON asset(tenant_id, type); | |
\ No newline at end of file | ||
39 | +CREATE INDEX IF NOT EXISTS idx_asset_type ON asset(tenant_id, type); | |
40 | + | |
41 | +CREATE INDEX IF NOT EXISTS idx_attribute_kv_by_key_and_last_update_ts ON attribute_kv(entity_id, attribute_key, last_update_ts desc); | |
\ No newline at end of file | ... | ... |