From 4f655c588505ec6957a723852740ebddf0c0acc8 Mon Sep 17 00:00:00 2001 From: admin user Date: Wed, 12 Mar 2025 16:18:58 +0000 Subject: [PATCH] DB lookup block --- README.md | 2 +- config.json | 16 ++++--- main.sql | 99 +++++++++++++++++++++++++++++++++++++++++++- request_schema.json | 23 +++++++++- response_schema.json | 12 +++++- 5 files changed, 142 insertions(+), 10 deletions(-) diff --git a/README.md b/README.md index 59a3efc..ba5ce57 100644 --- a/README.md +++ b/README.md @@ -1 +1 @@ -**Hello world!!!** +# DB Lookup Block diff --git a/config.json b/config.json index 41f8111..8c7adad 100644 --- a/config.json +++ b/config.json @@ -1,6 +1,10 @@ -[ - { - "namespace": "", - "connectionId": "" - } - ] \ No newline at end of file +[ + { + "namespace": "default", + "connectionId": "default" + }, + { + "namespace": "staging", + "connectionId": "e0f62962-1268-4bcf-b336-72ebfbe43578" + } +] diff --git a/main.sql b/main.sql index f0129ba..60f3688 100644 --- a/main.sql +++ b/main.sql @@ -1 +1,98 @@ -Select * from dummy_table limit 10; \ No newline at end of file +WITH abc AS ( + SELECT + DISTINCT + app.application_key, + CAST(app.application_timestamp AS TIMESTAMP) AS application_timestamp, + LOWER(app.application_email_address) AS application_email_address, + app.application_is_rejected, + NULLIF(app.application_ssn, '') AS application_ssn, + NULLIF(app.application_bank_account_number, '') AS application_bank_account_number, + loans.originated_loan_is_fraud, + loans.originated_loan_is_never_paid + FROM public.applications AS app + LEFT JOIN public.bridge_funding_lifecycle AS master + ON app.application_key = master.application_key + LEFT JOIN public.originated_loan AS loans + ON master.originated_loan_key = loans.originated_loan_key + -- WHERE app.application_customer_type = 'Direct New' +), + +current_app AS ( + SELECT + application_key AS current_app_key, + application_timestamp AS current_app_created_at, + $hd_score_m1 AS hd_score_m1 + FROM abc + WHERE application_key = $application_key +), + +connected_apps AS ( + SELECT + a.*, + a.application_key AS connected_app_key + FROM abc a + WHERE application_key = ANY(ARRAY$connected_application_keys::text[]) +), + +clusters_alt AS ( + SELECT + a.*, + b.current_app_key, + b.current_app_created_at, + b.hd_score_m1, + CASE + WHEN LOWER(CAST(a.originated_loan_is_fraud AS TEXT)) != 'true' + AND a.originated_loan_is_never_paid IS NULL THEN NULL + WHEN ABS(EXTRACT(DAY FROM AGE(b.current_app_created_at, a.application_timestamp))) > 29 + AND (LOWER(CAST(a.originated_loan_is_fraud AS TEXT)) = 'true' + OR LOWER(CAST(a.originated_loan_is_never_paid AS TEXT)) = 'true') + THEN 1 + ELSE 0 + END AS target_connected_30, + CONCAT(a.application_ssn, '_', a.application_bank_account_number) AS user_connected_v2, + a.application_timestamp AS connected_date, + a.application_email_address AS connected_email, + a.application_is_rejected AS application_is_rejected_connected + FROM connected_apps a + CROSS JOIN current_app b +), + +full_apps_past AS ( + SELECT + current_app_key, + SUM(target_connected_30) AS target_connected_30_sum, + COUNT(DISTINCT CASE + WHEN LOWER(CAST(application_is_rejected_connected AS TEXT)) = 'true' + THEN connected_app_key + ELSE NULL + END) AS rejected_app_count + FROM clusters_alt + WHERE current_app_key != connected_app_key + GROUP BY current_app_key +), + +clusters AS ( + SELECT + a.current_app_key AS application_key, + CAST(MAX(hd_score_m1) AS FLOAT) AS hd_score_m1, + COUNT(DISTINCT a.user_connected_v2) AS cluster_size_users_v2, + MAX(b.target_connected_30_sum) AS target_connected_30_sum, + COUNT(DISTINCT a.connected_email) AS email_cnt, + MAX(b.rejected_app_count) AS rejected_app_count, + COUNT(DISTINCT EXTRACT(DAY FROM DATE(a.connected_date))) AS app_dt_day_cnt, + COUNT(*) AS cluster_size + FROM clusters_alt a + LEFT JOIN full_apps_past b + ON a.current_app_key = b.current_app_key + GROUP BY 1 +) + +SELECT + COALESCE(MAX(hd_score_m1), $hd_score_m1) AS hd_score_m1, + COALESCE(MAX(cluster_size_users_v2), 0) AS cluster_size_users_v2, + COALESCE(MAX(target_connected_30_sum), 0) AS target_connected_30_sum, + COALESCE(MAX(email_cnt), 0) AS email_cnt, + COALESCE(MAX(rejected_app_count), 0) AS rejected_app_count, + COALESCE(MAX(app_dt_day_cnt), 0) AS app_dt_day_cnt, + COALESCE(MAX(cluster_size), 0) AS cluster_size +FROM clusters; \ No newline at end of file diff --git a/request_schema.json b/request_schema.json index 9e26dfe..02cd718 100644 --- a/request_schema.json +++ b/request_schema.json @@ -1 +1,22 @@ -{} \ No newline at end of file +{ + "$schema": "http://json-schema.org/draft-07/schema#", + "type": "object", + "properties": { + "application_key": { + "type": ["string", "null"], + "description": "Unique identifier for the application." + }, + "hd_score_m1": { + "type": ["number", "null"], + "description": "HD fraud score M1." + }, + "connected_application_keys": { + "type": "array", + "items": { + "type": ["string", "null"] + }, + "description": "List of connected application keys associated with this application." + } + }, + "required": [] +} diff --git a/response_schema.json b/response_schema.json index 9e26dfe..1ff4472 100644 --- a/response_schema.json +++ b/response_schema.json @@ -1 +1,11 @@ -{} \ No newline at end of file +{ + "$schema": "http://json-schema.org/draft-07/schema", + "type": "object", + "properties": { + "results": { + "type": ["array", "null"], + "items": {"type": "object"} + } + }, + "required": [] +} \ No newline at end of file