From 95bf5a3449a844a5a09f852d6a30071dff590633 Mon Sep 17 00:00:00 2001 From: sonikashah Date: Thu, 11 Jul 2024 01:31:37 +0530 Subject: [PATCH 1/5] Fixes #16788 : Fix feed and count api query performance --- .../mysql/postDataMigrationSQLScript.sql | 0 .../native/1.4.5/mysql/schemaChanges.sql | 60 ++++++ .../postgres/postDataMigrationSQLScript.sql | 0 .../native/1.4.5/postgres/schemaChanges.sql | 17 ++ .../service/jdbi3/CollectionDAO.java | 172 ++++++++++++------ .../service/jdbi3/EntityTimeSeriesDAO.java | 1 + 6 files changed, 192 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..6d61af395647 --- /dev/null +++ b/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql @@ -0,0 +1,60 @@ +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); + + +DELIMITER $$ + +CREATE PROCEDURE IF NOT EXISTS CreateIndexesIfNeeded() +BEGIN + SET @index_name_1 = 'idx_thread_entity_on_entityId'; + SET @table_name = 'thread_entity'; + SET @schema_name = DATABASE(); + + SELECT COUNT(1) INTO @index_exists_1 + FROM information_schema.statistics + WHERE table_schema = @schema_name + AND table_name = @table_name + AND index_name = @index_name_1; + + IF @index_exists_1 = 0 THEN + SET @create_index_sql_1 = CONCAT('CREATE INDEX ', @index_name_1, ' ON ', @table_name, ' (entityId)'); + PREPARE stmt1 FROM @create_index_sql_1; + EXECUTE stmt1; + DEALLOCATE PREPARE stmt1; + END IF; + + SET @index_name_2 = 'idx_thread_entity_on_type_taskStatus'; + + SELECT COUNT(1) INTO @index_exists_2 + FROM information_schema.statistics + WHERE table_schema = @schema_name + AND table_name = @table_name + AND index_name = @index_name_2; + + IF @index_exists_2 = 0 THEN + SET @create_index_sql_2 = CONCAT('CREATE INDEX ', @index_name_2, ' ON ', @table_name, ' (type, taskStatus)'); + PREPARE stmt2 FROM @create_index_sql_2; + EXECUTE stmt2; + DEALLOCATE PREPARE stmt2; + END IF; +END$$ + +DELIMITER ; + +-- Call the stored procedure to create indexes if not exist +CALL CreateIndexesIfNeeded(); + + + 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..f351d4fc958f --- /dev/null +++ b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql @@ -0,0 +1,17 @@ +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 TEXT GENERATED ALWAYS AS (jsonb -> '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_thread_entity_on_entityId ON thread_entity (entityId); + +CREATE INDEX idx_thread_entity_on_type_taskStatus 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 8f9dd1876b52..4175d3e59561 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 @@ -1140,16 +1140,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); @@ -1177,7 +1172,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 " @@ -1217,7 +1212,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 " @@ -1241,42 +1236,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, @@ -1313,15 +1324,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, @@ -1330,13 +1363,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, @@ -1344,7 +1400,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) " @@ -1359,7 +1415,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) ") diff --git a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java index 884287995370..9547a07db14e 100644 --- a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java +++ b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java @@ -363,6 +363,7 @@ String getLatestRecord( @Define("table") String table, @BindFQN("entityFQNHash") String entityFQNHash); default String getLatestRecord(String entityFQNHash) { + System.out.println("getLatestRecord: entityFQNHash= " + getTimeSeriesTableName()); return getLatestRecord(getTimeSeriesTableName(), entityFQNHash); } From b554d6e98ce8afdfc2046f3f8af4f7363006d1b0 Mon Sep 17 00:00:00 2001 From: sonikashah Date: Thu, 11 Jul 2024 01:34:05 +0530 Subject: [PATCH 2/5] Fixes #16788 : Fix feed and count api query performance --- .../java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java | 1 - 1 file changed, 1 deletion(-) diff --git a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java index 9547a07db14e..884287995370 100644 --- a/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java +++ b/openmetadata-service/src/main/java/org/openmetadata/service/jdbi3/EntityTimeSeriesDAO.java @@ -363,7 +363,6 @@ String getLatestRecord( @Define("table") String table, @BindFQN("entityFQNHash") String entityFQNHash); default String getLatestRecord(String entityFQNHash) { - System.out.println("getLatestRecord: entityFQNHash= " + getTimeSeriesTableName()); return getLatestRecord(getTimeSeriesTableName(), entityFQNHash); } From 8f2393852c95fe8d5fd0088b72e4bdd8796afc59 Mon Sep 17 00:00:00 2001 From: sonikashah Date: Thu, 11 Jul 2024 02:28:10 +0530 Subject: [PATCH 3/5] Fixes #16788 : Fix feed and count api query performance --- .../sql/migrations/native/1.4.5/postgres/schemaChanges.sql | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql index f351d4fc958f..2b2972791c15 100644 --- a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql @@ -1,5 +1,6 @@ ALTER TABLE thread_entity -ADD COLUMN hash_id VARCHAR(32) GENERATED ALWAYS AS (MD5(id)) STORED; +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 From 97079a255286328add6d304b089f43dbdac69022 Mon Sep 17 00:00:00 2001 From: sonikashah Date: Thu, 11 Jul 2024 02:34:49 +0530 Subject: [PATCH 4/5] postgres fixes --- .../sql/migrations/native/1.4.5/postgres/schemaChanges.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql index 2b2972791c15..1c55745cdd92 100644 --- a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql @@ -4,7 +4,7 @@ ADD COLUMN hash_id VARCHAR(32) CREATE INDEX idx_thread_entity_hash_id ON thread_entity(hash_id); ALTER TABLE thread_entity -ADD COLUMN testCaseResolutionStatusId TEXT GENERATED ALWAYS AS (jsonb -> 'task' ->> 'testCaseResolutionStatusId') STORED; +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 From fafba7a1a15b6306a4af4a961412012ec6967d04 Mon Sep 17 00:00:00 2001 From: sonikashah Date: Thu, 11 Jul 2024 12:11:38 +0530 Subject: [PATCH 5/5] rename thread_entity indexes --- .../native/1.4.5/mysql/schemaChanges.sql | 43 +------------------ .../native/1.4.5/postgres/schemaChanges.sql | 4 +- 2 files changed, 4 insertions(+), 43 deletions(-) diff --git a/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql index 6d61af395647..2b3d3fb82cd1 100644 --- a/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.4.5/mysql/schemaChanges.sql @@ -14,47 +14,8 @@ CREATE INDEX idx_field_relationship_from ON field_relationship (fromType, fromFQ CREATE INDEX idx_field_relationship_to ON field_relationship (fromType, toFQNHash, toType, relation); -DELIMITER $$ - -CREATE PROCEDURE IF NOT EXISTS CreateIndexesIfNeeded() -BEGIN - SET @index_name_1 = 'idx_thread_entity_on_entityId'; - SET @table_name = 'thread_entity'; - SET @schema_name = DATABASE(); - - SELECT COUNT(1) INTO @index_exists_1 - FROM information_schema.statistics - WHERE table_schema = @schema_name - AND table_name = @table_name - AND index_name = @index_name_1; - - IF @index_exists_1 = 0 THEN - SET @create_index_sql_1 = CONCAT('CREATE INDEX ', @index_name_1, ' ON ', @table_name, ' (entityId)'); - PREPARE stmt1 FROM @create_index_sql_1; - EXECUTE stmt1; - DEALLOCATE PREPARE stmt1; - END IF; - - SET @index_name_2 = 'idx_thread_entity_on_type_taskStatus'; - - SELECT COUNT(1) INTO @index_exists_2 - FROM information_schema.statistics - WHERE table_schema = @schema_name - AND table_name = @table_name - AND index_name = @index_name_2; - - IF @index_exists_2 = 0 THEN - SET @create_index_sql_2 = CONCAT('CREATE INDEX ', @index_name_2, ' ON ', @table_name, ' (type, taskStatus)'); - PREPARE stmt2 FROM @create_index_sql_2; - EXECUTE stmt2; - DEALLOCATE PREPARE stmt2; - END IF; -END$$ - -DELIMITER ; - --- Call the stored procedure to create indexes if not exist -CALL CreateIndexesIfNeeded(); +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/schemaChanges.sql b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql index 1c55745cdd92..69646fbffa51 100644 --- a/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql +++ b/bootstrap/sql/migrations/native/1.4.5/postgres/schemaChanges.sql @@ -13,6 +13,6 @@ 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_thread_entity_on_entityId ON thread_entity (entityId); +CREATE INDEX idx_entity_id ON thread_entity (entityId); -CREATE INDEX idx_thread_entity_on_type_taskStatus ON thread_entity (type, taskStatus); \ No newline at end of file +CREATE INDEX idx_type_task_status ON thread_entity (type, taskStatus); \ No newline at end of file