Skip to content

Commit

Permalink
Fixes #16788 : Fix feed and count api query performance (#16993)
Browse files Browse the repository at this point in the history
* Fixes #16788 : Fix feed and count api query performance

* Fixes #16788 : Fix feed and count api query performance

* Fixes #16788 : Fix feed and count api query performance

* postgres fixes

* rename thread_entity indexes
  • Loading branch information
sonika-shah committed Jul 11, 2024
1 parent f1efe53 commit 88265ec
Show file tree
Hide file tree
Showing 5 changed files with 153 additions and 58 deletions.
Empty file.
21 changes: 21 additions & 0 deletions bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
ALTER TABLE thread_entity
ADD COLUMN hash_id VARCHAR(32) GENERATED ALWAYS AS (MD5(id)) STORED;
CREATE INDEX idx_thread_entity_hash_id ON thread_entity(hash_id);

ALTER TABLE thread_entity
ADD COLUMN testCaseResolutionStatusId VARCHAR(255)
GENERATED ALWAYS AS (JSON_UNQUOTE(JSON_EXTRACT(json, '$.task.testCaseResolutionStatusId'))) STORED;
CREATE INDEX idx_testCaseResolutionStatusId ON thread_entity (testCaseResolutionStatusId);

CREATE INDEX idx_entity_relationship_fromEntity_fromId_relation
ON entity_relationship (fromEntity, fromId, relation);

CREATE INDEX idx_field_relationship_from ON field_relationship (fromType, fromFQNHash, toType, relation);
CREATE INDEX idx_field_relationship_to ON field_relationship (fromType, toFQNHash, toType, relation);


CREATE INDEX idx_entity_id ON thread_entity (entityId);

CREATE INDEX idx_type_task_status ON thread_entity (type, taskStatus);


Empty file.
18 changes: 18 additions & 0 deletions bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
ALTER TABLE thread_entity
ADD COLUMN hash_id VARCHAR(32)
GENERATED ALWAYS AS (MD5(json ->> 'id')) STORED;
CREATE INDEX idx_thread_entity_hash_id ON thread_entity(hash_id);

ALTER TABLE thread_entity
ADD COLUMN testCaseResolutionStatusId TEXT GENERATED ALWAYS AS (json -> 'task' ->> 'testCaseResolutionStatusId') STORED;
CREATE INDEX idx_testCaseResolutionStatusId ON thread_entity (testCaseResolutionStatusId);

CREATE INDEX idx_entity_relationship_fromEntity_fromId_relation
ON entity_relationship (fromEntity, fromId, relation);

CREATE INDEX idx_field_relationship_from ON field_relationship (fromType, fromFQNHash, toType, relation);
CREATE INDEX idx_field_relationship_to ON field_relationship (fromType, toFQNHash, toType, relation);

CREATE INDEX idx_entity_id ON thread_entity (entityId);

CREATE INDEX idx_type_task_status ON thread_entity (type, taskStatus);
Original file line number Diff line number Diff line change
Expand Up @@ -1109,16 +1109,11 @@ int listCountThreadsByOwner(
@BindList("teamIds") List<String> teamIds,
@Define("condition") String condition);

@ConnectionAwareSqlQuery(
value =
"SELECT json FROM thread_entity "
+ "WHERE (json -> '$.task.testCaseResolutionStatusId') = :testCaseResolutionStatusId; ",
connectionType = MYSQL)
@ConnectionAwareSqlQuery(
@SqlQuery(
value =
"SELECT json FROM thread_entity "
+ "WHERE (json#>'{task}'->>'testCaseResolutionStatusId') = :testCaseResolutionStatusId; ",
connectionType = POSTGRES)
"SELECT json "
+ " FROM thread_entity "
+ " WHERE testCaseResolutionStatusId = :testCaseResolutionStatusId")
String fetchThreadByTestCaseResolutionStatusId(
@BindUUID("testCaseResolutionStatusId") UUID testCaseResolutionStatusId);

Expand Down Expand Up @@ -1146,7 +1141,7 @@ default List<String> listThreadsByEntityLink(

@SqlQuery(
"SELECT json FROM thread_entity <condition> "
+ "AND MD5(id) in (SELECT fromFQNHash FROM field_relationship WHERE "
+ "AND hash_id in (SELECT fromFQNHash FROM field_relationship WHERE "
+ "(:fqnPrefixHash IS NULL OR toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR toFQNHash=:fqnPrefixHash) AND fromType='THREAD' AND "
+ "(:toType IS NULL OR toType LIKE CONCAT(:toType, '.%') OR toType=:toType) AND relation= :relation) "
+ "AND (:userName IS NULL OR MD5(id) in (SELECT toFQNHash FROM field_relationship WHERE "
Expand Down Expand Up @@ -1186,7 +1181,7 @@ default int listCountThreadsByEntityLink(

@SqlQuery(
"SELECT count(id) FROM thread_entity <condition> "
+ "AND MD5(id) in (SELECT fromFQNHash FROM field_relationship WHERE "
+ "AND hash_id in (SELECT fromFQNHash FROM field_relationship WHERE "
+ "(:fqnPrefixHash IS NULL OR toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR toFQNHash=:fqnPrefixHash) AND fromType='THREAD' AND "
+ "(:toType IS NULL OR toType LIKE CONCAT(:toType, '.%') OR toType=:toType) AND relation= :relation) "
+ "AND (:userName IS NULL OR id in (SELECT toFQNHash FROM field_relationship WHERE "
Expand All @@ -1210,42 +1205,58 @@ int listCountThreadsByEntityLink(
void update(@BindUUID("id") UUID id, @Bind("json") String json);

@SqlQuery(
"SELECT te.entityLink, te.type, te.taskStatus, COUNT(id) count FROM thread_entity te "
+ " where entityId = :entityId OR "
+ " MD5(id) in (SELECT fromFQNHash FROM field_relationship WHERE "
+ "(:fqnPrefixHash IS NULL OR toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR toFQNHash=:fqnPrefixHash) AND fromType='THREAD' AND "
+ "(:toType IS NULL OR toType LIKE CONCAT(:toType, '.%') OR toType=:toType) AND relation= 3) "
+ "GROUP BY te.type, te.taskStatus, entityLink")
"SELECT entityLink, type, taskStatus, COUNT(id) as count FROM ( "
+ " SELECT te.entityLink, te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " WHERE hash_id IN ( "
+ " SELECT fromFQNHash FROM field_relationship "
+ " WHERE "
+ " (:fqnPrefixHash IS NULL OR toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR toFQNHash = :fqnPrefixHash) "
+ " AND fromType = 'THREAD' "
+ " AND (:toType IS NULL OR toType LIKE CONCAT(:toType, '.%') OR toType = :toType) "
+ " AND relation = 3 "
+ " ) "
+ " UNION "
+ " SELECT te.entityLink, te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " WHERE te.entityId = :entityId "
+ ") AS combined "
+ "GROUP BY type, taskStatus, entityLink")
@RegisterRowMapper(ThreadCountFieldMapper.class)
List<List<String>> listCountByEntityLink(
@BindUUID("entityId") UUID entityId,
@BindFQN("fqnPrefixHash") String fqnPrefixHash,
@Bind("toType") String toType);

@ConnectionAwareSqlQuery(
value =
"SELECT te.type, te.taskStatus, COUNT(id) count FROM thread_entity te where "
+ "(entityId in (SELECT toId FROM entity_relationship WHERE "
+ "((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=8) OR "
+ "id in (SELECT toId FROM entity_relationship WHERE (fromEntity='user' AND fromId= :userId AND toEntity='THREAD' AND relation IN (1,2))) "
+ " OR id in (SELECT toId FROM entity_relationship WHERE ((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=11)) "
+ " OR (taskAssignees @> ANY (ARRAY[<userTeamJsonPostgres>]::jsonb[]) OR createdBy = :username)"
+ "GROUP BY te.type, te.taskStatus",
connectionType = POSTGRES)
@ConnectionAwareSqlQuery(
@SqlQuery(
value =
"SELECT te.type, te.taskStatus, COUNT(id) count FROM thread_entity te where "
+ "(entityId in (SELECT toId FROM entity_relationship WHERE "
+ "((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=8) OR "
+ "id in (SELECT toId FROM entity_relationship WHERE (fromEntity='user' AND fromId= :userId AND toEntity='THREAD' AND relation IN (1,2))) "
+ " OR id in (SELECT toId FROM entity_relationship WHERE ((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=11)) OR "
+ "(JSON_OVERLAPS(taskAssigneesIds, :userTeamJsonMysql) OR createdBy = :username)"
+ " GROUP BY te.type, te.taskStatus",
connectionType = MYSQL)
"SELECT combined.type, combined.taskStatus, COUNT(combined.id) AS count "
+ "FROM ( "
+ " SELECT te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " JOIN entity_relationship er ON te.entityId = er.toId "
+ " WHERE "
+ " (er.fromEntity = 'user' AND er.fromId = :userId AND er.relation = 8) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>) AND er.relation = 8) "
+ " UNION "
+ " SELECT te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " JOIN entity_relationship er ON te.id = er.toId "
+ " WHERE "
+ " er.fromEntity = 'user' AND er.fromId = :userId AND er.toEntity = 'THREAD' AND er.relation IN (1, 2) "
+ " UNION "
+ " SELECT te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " JOIN entity_relationship er ON te.id = er.toId "
+ " WHERE "
+ " (er.fromEntity = 'user' AND er.fromId = :userId AND er.relation = 11) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>) AND er.relation = 11) "
+ " UNION "
+ " SELECT te.type, te.taskStatus, te.id "
+ " FROM thread_entity te "
+ " WHERE te.createdBy = :username "
+ ") AS combined "
+ "GROUP BY combined.type, combined.taskStatus;")
@RegisterRowMapper(OwnerCountFieldMapper.class)
List<List<String>> listCountByOwner(
@BindUUID("userId") UUID userId,
Expand Down Expand Up @@ -1282,15 +1293,37 @@ int listCountThreadsByFollows(
@Define("condition") String condition);

@SqlQuery(
"SELECT json FROM thread_entity <condition> AND "
// Entity for which the thread is about is owned by the user or his teams
+ "(entityId in (SELECT toId FROM entity_relationship WHERE "
+ "((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=8) OR "
+ "id in (SELECT toId FROM entity_relationship WHERE (fromEntity='user' AND fromId= :userId AND toEntity='THREAD' AND relation IN (1,2))) "
+ " OR id in (SELECT toId FROM entity_relationship WHERE ((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=11)) "
+ "ORDER BY createdAt DESC "
"SELECT json FROM ( "
+ " SELECT json, createdAt FROM thread_entity te "
+ " <condition> AND entityId IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.relation = 8 "
+ " AND ( "
+ " (er.fromEntity = 'user' AND er.fromId = :userId) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>)) "
+ " ) "
+ " ) "
+ " UNION "
+ " SELECT json, createdAt FROM thread_entity te "
+ " <condition> AND id IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.toEntity = 'THREAD' "
+ " AND er.relation IN (1, 2) "
+ " AND er.fromEntity = 'user' "
+ " AND er.fromId = :userId "
+ " ) "
+ " UNION "
+ " SELECT json, createdAt FROM thread_entity te "
+ " <condition> AND id IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.relation = 11 "
+ " AND ( "
+ " (er.fromEntity = 'user' AND er.fromId = :userId) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>)) "
+ " ) "
+ " ) "
+ ") AS combined "
+ "ORDER BY createdAt DESC "
+ "LIMIT :limit")
List<String> listThreadsByOwnerOrFollows(
@BindUUID("userId") UUID userId,
Expand All @@ -1299,21 +1332,44 @@ List<String> listThreadsByOwnerOrFollows(
@Define("condition") String condition);

@SqlQuery(
"SELECT count(id) FROM thread_entity <condition> AND "
+ "(entityId in (SELECT toId FROM entity_relationship WHERE "
+ "((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=8) OR "
+ "id in (SELECT toId FROM entity_relationship WHERE (fromEntity='user' AND fromId= :userId AND toEntity='THREAD' AND relation IN (1,2))) "
+ " OR id in (SELECT toId FROM entity_relationship WHERE ((fromEntity='user' AND fromId= :userId) OR "
+ "(fromEntity='team' AND fromId IN (<teamIds>))) AND relation=11))")
"SELECT COUNT(id) FROM ( "
+ " SELECT te.id FROM thread_entity te "
+ " <condition> AND entityId IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.relation = 8 "
+ " AND ( "
+ " (er.fromEntity = 'user' AND er.fromId = :userId) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>)) "
+ " ) "
+ " ) "
+ " UNION "
+ " SELECT te.id FROM thread_entity te "
+ " <condition> AND id IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.toEntity = 'THREAD' "
+ " AND er.relation IN (1, 2) "
+ " AND er.fromEntity = 'user' "
+ " AND er.fromId = :userId "
+ " ) "
+ " UNION "
+ " SELECT te.id FROM thread_entity te "
+ " <condition> AND id IN ( "
+ " SELECT toId FROM entity_relationship er "
+ " WHERE er.relation = 11 "
+ " AND ( "
+ " (er.fromEntity = 'user' AND er.fromId = :userId) "
+ " OR (er.fromEntity = 'team' AND er.fromId IN (<teamIds>)) "
+ " ) "
+ " ) "
+ ") AS combined")
int listCountThreadsByOwnerOrFollows(
@BindUUID("userId") UUID userId,
@BindList("teamIds") List<String> teamIds,
@Define("condition") String condition);

@SqlQuery(
"SELECT json FROM thread_entity <condition> AND "
+ "MD5(id) in ("
+ "hash_id in ("
+ "SELECT toFQNHash FROM field_relationship WHERE "
+ "((fromType='user' AND fromFQNHash= :userName) OR "
+ "(fromType='team' AND fromFQNHash IN (<teamNames>))) AND toType='THREAD' AND relation= :relation) "
Expand All @@ -1328,7 +1384,7 @@ List<String> listThreadsByMentions(

@SqlQuery(
"SELECT count(id) FROM thread_entity <condition> AND "
+ "MD5(id) in ("
+ "hash_id in ("
+ "SELECT toFQNHash FROM field_relationship WHERE "
+ "((fromType='user' AND fromFQNHash= :userName) OR "
+ "(fromType='team' AND fromFQNHash IN (<teamNames>))) AND toType='THREAD' AND relation= :relation) ")
Expand Down

0 comments on commit 88265ec

Please sign in to comment.