Browse Source

alarms count: performance fix based on pg_stat analysis. Counters queries refactored as two subqueries: inner join (count with relations) + left 'anti' join (count without relations). AlarmServiceSqlTest passed. CE

pull/4460/head
Sergey Matvienko 5 years ago
committed by Andrew Shvayka
parent
commit
3228312cdb
  1. 36
      dao/src/main/java/org/thingsboard/server/dao/sql/alarm/AlarmRepository.java

36
dao/src/main/java/org/thingsboard/server/dao/sql/alarm/AlarmRepository.java

@ -50,23 +50,41 @@ public interface AlarmRepository extends CrudRepository<AlarmEntity, UUID> {
"AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
"AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
"AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
"AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%'))" +
"OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%'))" +
"OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%')))",
countQuery = "SELECT count(a) FROM AlarmEntity a " +
"LEFT JOIN RelationEntity re ON a.id = re.toId " +
"AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) "
,
countQuery = "" +
"SELECT count(a) + " + //alarms with relations only
" (SELECT count(a) FROM AlarmEntity a " + //alarms WITHOUT any relations
" LEFT JOIN RelationEntity re ON a.id = re.toId " +
" AND re.relationTypeGroup = 'ALARM' " +
" AND re.toType = 'ALARM' " +
" AND re.fromId = :affectedEntityId " +
" AND re.fromType = :affectedEntityType " +
" WHERE a.tenantId = :tenantId " +
" AND (a.originatorId = :affectedEntityId) " +
" AND (re.fromId IS NULL) " + //anti join
" AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
" AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
" AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
" AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) " +
" )" +
"FROM AlarmEntity a " +
"INNER JOIN RelationEntity re ON a.id = re.toId " +
"AND re.relationTypeGroup = 'ALARM' " +
"AND re.toType = 'ALARM' " +
"AND re.fromId = :affectedEntityId " +
"AND re.fromType = :affectedEntityType " +
"WHERE a.tenantId = :tenantId " +
"AND (a.originatorId = :affectedEntityId or re.fromId IS NOT NULL) " +
"AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
"AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
"AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
"AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%'))" +
"OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%'))" +
"OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%')))")
"AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
" OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) ")
Page<AlarmInfoEntity> findAlarms(@Param("tenantId") UUID tenantId,
@Param("affectedEntityId") UUID affectedEntityId,
@Param("affectedEntityType") String affectedEntityType,

Loading…
Cancel
Save