Commit 3228312cdb66bbbe35ca1494de83bae384bcbc13

Authored by Sergey Matvienko
Committed by Andrew Shvayka
1 parent 08d9ea30

alarms count: performance fix based on pg_stat analysis. Counters queries refact…

…ored as two subqueries: inner join (count with relations) + left 'anti' join (count without relations). AlarmServiceSqlTest passed. CE
... ... @@ -50,23 +50,41 @@ public interface AlarmRepository extends CrudRepository<AlarmEntity, UUID> {
50 50 "AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
51 51 "AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
52 52 "AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
53   - "AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%'))" +
54   - "OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%'))" +
55   - "OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%')))",
56   - countQuery = "SELECT count(a) FROM AlarmEntity a " +
57   - "LEFT JOIN RelationEntity re ON a.id = re.toId " +
  53 + "AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
  54 + " OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
  55 + " OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) "
  56 + ,
  57 + countQuery = "" +
  58 + "SELECT count(a) + " + //alarms with relations only
  59 + " (SELECT count(a) FROM AlarmEntity a " + //alarms WITHOUT any relations
  60 + " LEFT JOIN RelationEntity re ON a.id = re.toId " +
  61 + " AND re.relationTypeGroup = 'ALARM' " +
  62 + " AND re.toType = 'ALARM' " +
  63 + " AND re.fromId = :affectedEntityId " +
  64 + " AND re.fromType = :affectedEntityType " +
  65 + " WHERE a.tenantId = :tenantId " +
  66 + " AND (a.originatorId = :affectedEntityId) " +
  67 + " AND (re.fromId IS NULL) " + //anti join
  68 + " AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
  69 + " AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
  70 + " AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
  71 + " AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
  72 + " OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
  73 + " OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) " +
  74 + " )" +
  75 + "FROM AlarmEntity a " +
  76 + "INNER JOIN RelationEntity re ON a.id = re.toId " +
58 77 "AND re.relationTypeGroup = 'ALARM' " +
59 78 "AND re.toType = 'ALARM' " +
60 79 "AND re.fromId = :affectedEntityId " +
61 80 "AND re.fromType = :affectedEntityType " +
62 81 "WHERE a.tenantId = :tenantId " +
63   - "AND (a.originatorId = :affectedEntityId or re.fromId IS NOT NULL) " +
64 82 "AND (:startTime IS NULL OR a.createdTime >= :startTime) " +
65 83 "AND (:endTime IS NULL OR a.createdTime <= :endTime) " +
66 84 "AND ((:alarmStatuses) IS NULL OR a.status in (:alarmStatuses)) " +
67   - "AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%'))" +
68   - "OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%'))" +
69   - "OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%')))")
  85 + "AND (LOWER(a.type) LIKE LOWER(CONCAT(:searchText, '%')) " +
  86 + " OR LOWER(a.severity) LIKE LOWER(CONCAT(:searchText, '%')) " +
  87 + " OR LOWER(a.status) LIKE LOWER(CONCAT(:searchText, '%'))) ")
70 88 Page<AlarmInfoEntity> findAlarms(@Param("tenantId") UUID tenantId,
71 89 @Param("affectedEntityId") UUID affectedEntityId,
72 90 @Param("affectedEntityType") String affectedEntityType,
... ...