From d2ac1eb1767c4f3658c88e64f0e6791781fb426c Mon Sep 17 00:00:00 2001 From: Maria Martinez <77364706+mamartinezmejia@users.noreply.github.com> Date: Mon, 25 Nov 2024 09:16:27 -0800 Subject: [PATCH] feat(be): Optimized search query (#1312) * feat(be): Made search query a bit faster * fix(be): Code reviews * fix(be): Code reviews * Added test when name part is the contatenation * no message --------- Co-authored-by: Paulo Gomes da Cruz Junior --- .../repository/ForestClientRepository.java | 179 +++++++++++------- ...ClientSearchControllerIntegrationTest.java | 3 +- 2 files changed, 115 insertions(+), 67 deletions(-) diff --git a/legacy/src/main/java/ca/bc/gov/app/repository/ForestClientRepository.java b/legacy/src/main/java/ca/bc/gov/app/repository/ForestClientRepository.java index 7428a464b1..d23343c824 100644 --- a/legacy/src/main/java/ca/bc/gov/app/repository/ForestClientRepository.java +++ b/legacy/src/main/java/ca/bc/gov/app/repository/ForestClientRepository.java @@ -62,53 +62,77 @@ Flux findClientByIncorporationOrName( @Query(""" SELECT - c.client_number, - c.CLIENT_ACRONYM as client_acronym, - c.client_name, - c.legal_first_name as client_first_name, - dba.doing_business_as_name as doing_business_as, - c.client_identification, - c.legal_middle_name as client_middle_name, - cl.city as city, - ctc.description as client_type, - csc.description as client_status, - ( - CASE WHEN c.client_number = :value THEN 112 ELSE 0 END + - CASE WHEN c.CLIENT_ACRONYM = :value THEN 111 ELSE 0 END + - (UTL_MATCH.JARO_WINKLER_SIMILARITY(c.client_name, :value)+10) + - (UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_first_name, :value)+9) + - (UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name, :value)+7) + - CASE WHEN c.client_identification = :value THEN 106 ELSE 0 END + - UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name, :value) - ) AS score - FROM the.forest_client c - LEFT JOIN the.CLIENT_DOING_BUSINESS_AS dba ON c.client_number = dba.client_number - LEFT JOIN the.CLIENT_TYPE_CODE ctc ON c.client_type_code = ctc.client_type_code - LEFT JOIN the.CLIENT_LOCATION cl ON c.client_number = cl.client_number - LEFT JOIN the.CLIENT_STATUS_CODE csc ON c.client_status_code = csc.client_status_code - WHERE - ( - c.client_number = :value - OR c.CLIENT_ACRONYM = :value - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.client_name,:value) >= 90 - OR c.client_name LIKE '%' || :value || '%' - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_first_name,:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name,:value) >= 90 - OR dba.doing_business_as_name LIKE '%' || :value || '%' - OR c.client_identification = :value - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name,:value) >= 90 - OR c.legal_middle_name LIKE '%' || :value || '%' - OR (c.client_type_code = 'I' AND ( - UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.legal_first_name || ' ', '') || COALESCE(c.legal_middle_name || ' ', '') || COALESCE(c.client_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.legal_first_name || ' ', '') || COALESCE(c.client_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.client_name || ' ', '') || COALESCE(c.legal_middle_name || ' ', '') || COALESCE(c.legal_first_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.client_name || ' ', '') || COALESCE(c.legal_first_name, '')),:value) >= 90 - ) - ) - ) AND - cl.CLIENT_LOCN_CODE = '00' - ORDER BY score DESC - OFFSET :offset ROWS FETCH NEXT :limit ROWS ONLY""") + c.client_number, + c.CLIENT_ACRONYM AS client_acronym, + c.client_name, + c.legal_first_name AS client_first_name, + dba.doing_business_as_name AS doing_business_as, + c.client_identification, + c.legal_middle_name AS client_middle_name, + cl.city AS city, + ctc.description AS client_type, + csc.description AS client_status, + ( + CASE WHEN c.client_number = :value THEN 112 ELSE 0 END + + CASE WHEN c.CLIENT_ACRONYM = :value THEN 111 ELSE 0 END + + (UTL_MATCH.JARO_WINKLER_SIMILARITY( + c.client_name || ' ' || c.legal_first_name, :value + ) + 10) + + (UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name, :value) + 7) + + CASE WHEN c.client_identification = :value THEN 106 ELSE 0 END + + UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name, :value) + ) AS score + FROM the.forest_client c + LEFT JOIN the.CLIENT_DOING_BUSINESS_AS dba ON c.client_number = dba.client_number + LEFT JOIN the.CLIENT_TYPE_CODE ctc ON c.client_type_code = ctc.client_type_code + LEFT JOIN the.CLIENT_LOCATION cl ON c.client_number = cl.client_number + LEFT JOIN the.CLIENT_STATUS_CODE csc ON c.client_status_code = csc.client_status_code + WHERE + ( + c.client_number = :value + OR c.CLIENT_ACRONYM = :value + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.client_name, :value) >= 90 + OR c.client_name LIKE '%' || :value || '%' + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_first_name, :value) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name, :value) >= 90 + OR dba.doing_business_as_name LIKE '%' || :value || '%' + OR c.client_identification = :value + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name, :value) >= 90 + OR c.legal_middle_name LIKE '%' || :value || '%' + OR ( + c.client_type_code = 'I' AND ( + UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.legal_first_name, '') || ' ' || + COALESCE(c.legal_middle_name, '') || + COALESCE(c.client_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.legal_first_name, '') || ' ' || + COALESCE(c.client_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.client_name, '') || ' ' || + COALESCE(c.legal_middle_name, '') || + COALESCE(c.legal_first_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.client_name, '') || ' ' || + COALESCE(c.legal_first_name, '') + ), :value + ) >= 90 + ) + ) + ) + AND cl.CLIENT_LOCN_CODE = '00' + ORDER BY score DESC + OFFSET :offset ROWS FETCH NEXT :limit ROWS ONLY""") Flux findByPredictiveSearch(String value, int limit, long offset); @Query(""" @@ -120,26 +144,49 @@ Flux findClientByIncorporationOrName( LEFT JOIN the.CLIENT_LOCATION cl ON c.client_number = cl.client_number LEFT JOIN the.CLIENT_STATUS_CODE csc ON c.client_status_code = csc.client_status_code WHERE - ( - c.client_number = :value - OR c.CLIENT_ACRONYM = :value - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.client_name,:value) >= 90 - OR c.client_name LIKE '%' || :value || '%' - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_first_name,:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name,:value) >= 90 - OR dba.doing_business_as_name LIKE '%' || :value || '%' - OR c.client_identification = :value - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name,:value) >= 90 - OR c.legal_middle_name LIKE '%' || :value || '%' - OR (c.client_type_code = 'I' AND ( - UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.legal_first_name || ' ', '') || COALESCE(c.legal_middle_name || ' ', '') || COALESCE(c.client_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.legal_first_name || ' ', '') || COALESCE(c.client_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.client_name || ' ', '') || COALESCE(c.legal_middle_name || ' ', '') || COALESCE(c.legal_first_name, '')),:value) >= 90 - OR UTL_MATCH.JARO_WINKLER_SIMILARITY(TRIM(COALESCE(c.client_name || ' ', '') || COALESCE(c.legal_first_name, '')),:value) >= 90 - ) + ( + c.client_number = :value + OR c.CLIENT_ACRONYM = :value + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.client_name, :value) >= 90 + OR c.client_name LIKE '%' || :value || '%' + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_first_name, :value) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(dba.doing_business_as_name, :value) >= 90 + OR dba.doing_business_as_name LIKE '%' || :value || '%' + OR c.client_identification = :value + OR UTL_MATCH.JARO_WINKLER_SIMILARITY(c.legal_middle_name, :value) >= 90 + OR c.legal_middle_name LIKE '%' || :value || '%' + OR ( + c.client_type_code = 'I' AND ( + UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.legal_first_name, '') || ' ' || + COALESCE(c.legal_middle_name, '') || + COALESCE(c.client_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.legal_first_name, '') || ' ' || + COALESCE(c.client_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.client_name, '') || ' ' || + COALESCE(c.legal_middle_name, '') || + COALESCE(c.legal_first_name, '') + ), :value + ) >= 90 + OR UTL_MATCH.JARO_WINKLER_SIMILARITY( + TRIM( + COALESCE(c.client_name, '') || ' ' || + COALESCE(c.legal_first_name, '') + ), :value + ) >= 90 + ) + ) ) - ) AND - cl.CLIENT_LOCN_CODE = '00'""") + AND cl.CLIENT_LOCN_CODE = '00'""") Mono countByPredictiveSearch(String value); @Query(""" diff --git a/legacy/src/test/java/ca/bc/gov/app/controller/ClientSearchControllerIntegrationTest.java b/legacy/src/test/java/ca/bc/gov/app/controller/ClientSearchControllerIntegrationTest.java index 5d816ef7ce..8489dfd236 100644 --- a/legacy/src/test/java/ca/bc/gov/app/controller/ClientSearchControllerIntegrationTest.java +++ b/legacy/src/test/java/ca/bc/gov/app/controller/ClientSearchControllerIntegrationTest.java @@ -574,7 +574,8 @@ private static Stream byPredictive() { Arguments.of("darbie", 0, 4, "00000145", "DARBIE BLIND (MINYX)"), Arguments.of("pietro", null, null, StringUtils.EMPTY, StringUtils.EMPTY), Arguments.of("pietro", 0, 5, StringUtils.EMPTY, StringUtils.EMPTY), - Arguments.of("pietro", 4, 10, StringUtils.EMPTY, StringUtils.EMPTY) + Arguments.of("pietro", 4, 10, StringUtils.EMPTY, StringUtils.EMPTY), + Arguments.of("matelda", null, null, "00000137", "MATELDA LINDHE (JABBERTYPE)") ); }