From 5dcce6d14819632f004ab27d1d95f76017a062d9 Mon Sep 17 00:00:00 2001 From: "michele.artini" Date: Tue, 22 Jun 2021 11:50:08 +0200 Subject: [PATCH] sql performance: removed join with view --- .../OrganizationSimpleViewRepository.java | 47 ++++++++++++++++++- 1 file changed, 45 insertions(+), 2 deletions(-) diff --git a/apps/dnet-orgs-database-application/src/main/java/eu/dnetlib/organizations/repository/readonly/OrganizationSimpleViewRepository.java b/apps/dnet-orgs-database-application/src/main/java/eu/dnetlib/organizations/repository/readonly/OrganizationSimpleViewRepository.java index ee5fdc7d..13325fad 100644 --- a/apps/dnet-orgs-database-application/src/main/java/eu/dnetlib/organizations/repository/readonly/OrganizationSimpleViewRepository.java +++ b/apps/dnet-orgs-database-application/src/main/java/eu/dnetlib/organizations/repository/readonly/OrganizationSimpleViewRepository.java @@ -14,11 +14,54 @@ import eu.dnetlib.organizations.model.view.OrganizationSimpleView; public interface OrganizationSimpleViewRepository extends ReadOnlyRepository { // SEARCH - @Query(value = "select o.* from organizations_simple_view o left outer join org_index_search idx on (idx.id = o.id) where idx.txt @@ plainto_tsquery(:text) and o.status in :statuses order by o.name", nativeQuery = true) + @Query(value = "SELECT \n" + + " org.id,\n" + + " org.name,\n" + + " org.type,\n" + + " org.city,\n" + + " org.country,\n" + + " org.status,\n" + + " array_remove(array_agg(DISTINCT a.acronym), NULL) AS acronyms,\n" + + " array_remove(array_agg(DISTINCT u.url), NULL) AS urls,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'is_similar') AS n_similar_dups,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'suggested') AS n_suggested_dups,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'is_different') AS n_different_dups,\n" + + " org.status = 'raw' AND NOT ('is_similar' = ANY (array_agg(d2.reltype))) AS candidate_dup\n" + + "FROM org_index_search idx " + + " JOIN organizations org ON (idx.id = org.id) \n" + + " LEFT OUTER JOIN acronyms a ON org.id = a.id\n" + + " LEFT OUTER JOIN urls u ON org.id = u.id\n" + + " LEFT OUTER JOIN oa_duplicates d1 ON org.id = d1.local_id\n" + + " LEFT OUTER JOIN oa_duplicates d2 ON org.id = d2.oa_original_id\n" + + "WHERE idx.txt @@ plainto_tsquery(:text) AND org.status in :statuses\n" + + "GROUP BY org.id, org.name, org.type, org.city, org.country, org.status\n" + + "ORDER BY org.name", nativeQuery = true) Page search(@Param("text") String text, @Param("statuses") List statuses, Pageable pageable); // SEARCH FOR USER - @Query(value = "select o.* from organizations_simple_view o left outer join org_index_search idx on (idx.id = o.id) left outer join user_countries uc on (uc.country = o.country) where idx.txt @@ plainto_tsquery(:text) and uc.email = :email and o.status in :statuses order by o.name", nativeQuery = true) + @Query(value = "SELECT\n" + + " org.id,\n" + + " org.name,\n" + + " org.type,\n" + + " org.city,\n" + + " org.country,\n" + + " org.status,\n" + + " array_remove(array_agg(DISTINCT a.acronym), NULL) AS acronyms,\n" + + " array_remove(array_agg(DISTINCT u.url), NULL) AS urls,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'is_similar' ) AS n_similar_dups,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'suggested' ) AS n_suggested_dups,\n" + + " count(DISTINCT d1.oa_original_id) FILTER (WHERE d1.reltype = 'is_different') AS n_different_dups,\n" + + " (org.status = 'raw' AND not('is_similar' = ANY(array_agg(d2.reltype)))) AS candidate_dup\n" + + "FROM org_index_search idx\n" + + " JOIN organizations org ON (idx.id = org.id)\n" + + " LEFT OUTER JOIN acronyms a ON (org.id = a.id)\n" + + " LEFT OUTER JOIN urls u ON (org.id = u.id)\n" + + " LEFT OUTER JOIN oa_duplicates d1 ON (org.id = d1.local_id)\n" + + " LEFT OUTER JOIN oa_duplicates d2 ON (org.id = d2.oa_original_id)\n" + + " LEFT OUTER JOIN user_countries uc ON (uc.country = org.country) \n" + + "WHERE idx.txt @@ plainto_tsquery(:text) AND uc.email = :email AND org.status IN :statuses \n" + + "GROUP BY org.id, org.name, org.type, org.city, org.country, org.status\n" + + "ORDER BY org.name", nativeQuery = true) Page searchForUser(@Param("text") String text, @Param("email") String email, @Param("statuses") List statuses,