Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat(be): Optimized search query #1312

Merged
merged 10 commits into from
Nov 25, 2024
Original file line number Diff line number Diff line change
Expand Up @@ -62,53 +62,77 @@ Flux<ForestClientEntity> 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<PredictiveSearchResultDto> findByPredictiveSearch(String value, int limit, long offset);

@Query("""
Expand All @@ -120,26 +144,49 @@ Flux<ForestClientEntity> 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<Long> countByPredictiveSearch(String value);

@Query("""
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -574,7 +574,8 @@ private static Stream<Arguments> 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)")
);
}

Expand Down
Loading