From 88265ecf4a7aa1060bfd64f397b14cacf7acf972 Mon Sep 17 00:00:00 2001 From: sonika-shah <58761340+sonika-shah@users.noreply.github.com> Date: Thu, 11 Jul 2024 14:18:33 +0530 Subject: [PATCH] Fixes #16788 : Fix feed and count api query performance (#16993) * 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 --- .../mysql/postDataMigrationSQLScript.sql | 0 .../native/1.4.5/mysql/schemaChanges.sql | 21 +++ .../postgres/postDataMigrationSQLScript.sql | 0 .../native/1.4.5/postgres/schemaChanges.sql | 18 ++ .../service/jdbi3/CollectionDAO.java | 172 ++++++++++++------ 5 files changed, 153 insertions(+), 58 deletions(-) create mode 100644 bootstrap/sql/migrations/native/1.4.5/mysql/postDataMigrationSQLScript.sql create mode 100644 bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql create mode 100644 bootstrap/sql/migrations/native/1.4.5/postgres/postDataMigrationSQLScript.sql create mode 100644 bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql diff --git a/bootstrap/sql/migrations/native/1.4.5/mysql/postDataMigrationSQLScript.sql b/bootstrap/sql/migrations/native/1.4.5/mysql/postDataMigrationSQLScript.sql new file mode 100644 index 000000000000..e69de29bb2d1 diff --git a/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql new file mode 100644 index 000000000000..2b3d3fb82cd1 --- /dev/null +++ b/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql @@ -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); + + diff --git a/bootstrap/sql/migrations/native/1.4.5/postgres/postDataMigrationSQLScript.sql b/bootstrap/sql/migrations/native/1.4.5/postgres/postDataMigrationSQLScript.sql new file mode 100644 index 000000000000..e69de29bb2d1 diff --git a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql new file mode 100644 index 000000000000..69646fbffa51 --- /dev/null +++ b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql @@ -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); \ No newline at end of file diff --git a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/CollectionDAO.java b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/CollectionDAO.java index 1084ebf4bc78..3648d378f67d 100644 --- a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/CollectionDAO.java +++ b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/CollectionDAO.java @@ -1109,16 +1109,11 @@ int listCountThreadsByOwner( @BindList("teamIds") List 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); @@ -1146,7 +1141,7 @@ default List listThreadsByEntityLink( @SqlQuery( "SELECT json FROM thread_entity " - + "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 " @@ -1186,7 +1181,7 @@ default int listCountThreadsByEntityLink( @SqlQuery( "SELECT count(id) FROM thread_entity " - + "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 " @@ -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> 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 ())) 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 ())) AND relation=11)) " - + " OR (taskAssignees @> ANY (ARRAY[]::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 ())) 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 ())) 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 () 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 () 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> listCountByOwner( @BindUUID("userId") UUID userId, @@ -1282,15 +1293,37 @@ int listCountThreadsByFollows( @Define("condition") String condition); @SqlQuery( - "SELECT json FROM thread_entity 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 ())) 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 ())) AND relation=11)) " - + "ORDER BY createdAt DESC " + "SELECT json FROM ( " + + " SELECT json, createdAt FROM thread_entity te " + + " 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 ()) " + + " ) " + + " ) " + + " UNION " + + " SELECT json, createdAt FROM thread_entity te " + + " 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 " + + " 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 ()) " + + " ) " + + " ) " + + ") AS combined " + + "ORDER BY createdAt DESC " + "LIMIT :limit") List listThreadsByOwnerOrFollows( @BindUUID("userId") UUID userId, @@ -1299,13 +1332,36 @@ List listThreadsByOwnerOrFollows( @Define("condition") String condition); @SqlQuery( - "SELECT count(id) FROM thread_entity AND " - + "(entityId in (SELECT toId FROM entity_relationship WHERE " - + "((fromEntity='user' AND fromId= :userId) OR " - + "(fromEntity='team' AND fromId IN ())) 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 ())) AND relation=11))") + "SELECT COUNT(id) FROM ( " + + " SELECT te.id FROM thread_entity te " + + " 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 ()) " + + " ) " + + " ) " + + " UNION " + + " SELECT te.id FROM thread_entity te " + + " 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 " + + " 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 ()) " + + " ) " + + " ) " + + ") AS combined") int listCountThreadsByOwnerOrFollows( @BindUUID("userId") UUID userId, @BindList("teamIds") List teamIds, @@ -1313,7 +1369,7 @@ int listCountThreadsByOwnerOrFollows( @SqlQuery( "SELECT json FROM thread_entity AND " - + "MD5(id) in (" + + "hash_id in (" + "SELECT toFQNHash FROM field_relationship WHERE " + "((fromType='user' AND fromFQNHash= :userName) OR " + "(fromType='team' AND fromFQNHash IN ())) AND toType='THREAD' AND relation= :relation) " @@ -1328,7 +1384,7 @@ List listThreadsByMentions( @SqlQuery( "SELECT count(id) FROM thread_entity AND " - + "MD5(id) in (" + + "hash_id in (" + "SELECT toFQNHash FROM field_relationship WHERE " + "((fromType='user' AND fromFQNHash= :userName) OR " + "(fromType='team' AND fromFQNHash IN ())) AND toType='THREAD' AND relation= :relation) ")