diff --git a/bootstrap/sql/migrations/native/1.5.0/mysql/schemaChanges.sql b/bootstrap/sql/migrations/native/1.5.0/mysql/schemaChanges.sql index d1ffccd6ebe..7b69652dab0 100644 --- a/bootstrap/sql/migrations/native/1.5.0/mysql/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.5.0/mysql/schemaChanges.sql @@ -329,3 +329,8 @@ ADD COLUMN taskAssigneesIds TEXT GENERATED ALWAYS AS ( ) STORED; CREATE FULLTEXT INDEX taskAssigneesIds_index ON thread_entity(taskAssigneesIds); + +-- Add indexes on thread_entity and entity_relationship to improve count/feed api performance +CREATE INDEX idx_thread_entity_entityId_createdAt ON thread_entity (entityId, createdAt); +CREATE INDEX idx_thread_entity_id_type_status ON thread_entity (id, type, taskStatus); +CREATE INDEX idx_er_fromEntity_fromId_toEntity_relation ON entity_relationship (fromEntity, fromId, toEntity, relation); \ No newline at end of file diff --git a/bootstrap/sql/migrations/native/1.5.0/postgres/schemaChanges.sql b/bootstrap/sql/migrations/native/1.5.0/postgres/schemaChanges.sql index 490260e0f40..49dd275e8b5 100644 --- a/bootstrap/sql/migrations/native/1.5.0/postgres/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.5.0/postgres/schemaChanges.sql @@ -299,3 +299,9 @@ ADD COLUMN taskAssigneesIds TEXT GENERATED ALWAYS AS ( CREATE INDEX idx_task_assignees_ids_fulltext ON thread_entity USING GIN (to_tsvector('simple', taskAssigneesIds)); + + +-- Add indexes on thread_entity and entity_relationship to improve count/feed api performance +CREATE INDEX idx_thread_entity_entityId_createdAt ON thread_entity (entityId, createdAt); +CREATE INDEX idx_thread_entity_id_type_status ON thread_entity (id, type, taskStatus); +CREATE INDEX idx_er_fromEntity_fromId_toEntity_relation ON entity_relationship (fromEntity, fromId, toEntity, relation); 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 59749c5041e..a7d214e38d7 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 @@ -1594,36 +1594,35 @@ public interface CollectionDAO { } @SqlQuery( - "SELECT entityLink, type, taskStatus, COUNT(id) count " + "SELECT entityLink, type, taskStatus, COUNT(id) as count " + "FROM ( " + " SELECT te.entityLink, te.type, te.taskStatus, te.id " - + " FROM thread_entity te " - + " WHERE te.entityId = :entityId " - + " OR EXISTS ( " - + " SELECT 1 " - + " FROM field_relationship fr " - + " WHERE fr.fromFQNHash = MD5(te.id) " - + " AND (:fqnPrefixHash IS NULL OR fr.toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR fr.toFQNHash = :fqnPrefixHash) " + + " FROM thread_entity te " + + " WHERE te.entityId = :entityId " + + " UNION " + + " SELECT te.entityLink, te.type, te.taskStatus, te.id " + + " FROM thread_entity te " + + " WHERE te.hash_id IN ( " + + " SELECT fr.fromFQNHash " + + " FROM field_relationship fr " + + " WHERE (:fqnPrefixHash IS NULL OR fr.toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR fr.toFQNHash = :fqnPrefixHash) " + " AND fr.fromType = 'THREAD' " + " AND (:toType1 IS NULL OR fr.toType LIKE CONCAT(:toType1, '.%') OR fr.toType = :toType1) " + " AND fr.relation = 3 " + " ) " - + " UNION ALL " + + " UNION " + " SELECT te.entityLink, te.type, te.taskStatus, te.id " - + " FROM thread_entity te " - + " WHERE te.type = 'Task' " - + " AND ( " - + " EXISTS ( " - + " SELECT 1 " - + " FROM field_relationship fr " - + " JOIN thread_entity te2 ON MD5(te2.id) = fr.fromFQNHash " - + " WHERE fr.fromFQNHash = MD5(te.id) " - + " AND te2.type = 'Task' " + + " FROM thread_entity te " + + " WHERE te.type = 'Task' " + + " AND te.hash_id IN ( " + + " SELECT fr.fromFQNHash " + + " FROM field_relationship fr " + + " JOIN thread_entity te2 ON te2.hash_id = fr.fromFQNHash WHERE fr.fromFQNHash = te.hash_id AND te2.type = 'Task' " + " AND (:fqnPrefixHash IS NULL OR fr.toFQNHash LIKE CONCAT(:fqnPrefixHash, '.%') OR fr.toFQNHash = :fqnPrefixHash) " + " AND fr.fromType = 'THREAD' " + " AND (:toType2 IS NULL OR fr.toType LIKE CONCAT(:toType2, '.%') OR fr.toType = :toType2) " + " AND fr.relation = 3 " - + " )) " + + " ) " + ") AS combined_results " + "GROUP BY entityLink, type, taskStatus ") @RegisterRowMapper(ThreadCountFieldMapper.class)