From 02b494de91824f4a066812c218a464a337dc6b05 Mon Sep 17 00:00:00 2001 From: psodhi-gds <129272850+psodhi-gds@users.noreply.github.com> Date: Mon, 23 Oct 2023 10:53:03 +0100 Subject: [PATCH] No int test/dap ipv identity issued (#384) * ipv_identity_issue changes * update to ref table * update to temp view and proc * update to set up file * update to proc --- .../redshift_scripts/sp_ipv_journey.sql | 34 +- .../sp_setup_conformed_schema_statements.sql | 3 +- .../alter_fact_user_journey_event_iii.sql | 9 + ...licate_event_id_ipv_identity_issued_15.sql | 9 + .../redshift_setup_process_scripts.sql | 16 + redshift-scripts/setup_process/ref_events.sql | 4 + .../sp_conformed_stage_view_data_objects.sql | 3 + ...p_ipv_journey_ipv_identity_issued_temp.sql | 387 ++++++++++++++++++ ...g_ipv_journey_ipv_identity_issued_temp.sql | 60 +++ 9 files changed, 516 insertions(+), 9 deletions(-) create mode 100644 redshift-scripts/setup_process/alter_fact_user_journey_event_iii.sql create mode 100644 redshift-scripts/setup_process/create_err_duplicate_event_id_ipv_identity_issued_15.sql create mode 100644 redshift-scripts/setup_process/sp_ipv_journey_ipv_identity_issued_temp.sql create mode 100644 redshift-scripts/setup_process/v_stg_ipv_journey_ipv_identity_issued_temp.sql diff --git a/athena-scripts/redshift_scripts/sp_ipv_journey.sql b/athena-scripts/redshift_scripts/sp_ipv_journey.sql index 2ad0c592f..d45136369 100644 --- a/athena-scripts/redshift_scripts/sp_ipv_journey.sql +++ b/athena-scripts/redshift_scripts/sp_ipv_journey.sql @@ -179,13 +179,22 @@ P Sodhi 15/09/2023 Removed update to the RP table as its not needed. WHERE sub_domain NOT IN (SELECT VERIFICATION_ROUTE_NAME FROM conformed.DIM_VERIFICATION_ROUTE); - UPDATE "dap_txma_reporting_db"."conformed"."fact_user_journey_event" + UPDATE "conformed"."fact_user_journey_event" SET REJECTION_REASON=trim(st.REJECTION_REASON,'"') ,REASON=trim(st.REASON,'"') ,USER_USER_ID=st.user_user_id ,USER_GOVUK_SIGNIN_JOURNEY_ID=st.user_govuk_signin_journey_id - ,COMPONENT_ID=st.COMPONENT_ID + ,COMPONENT_ID=st.COMPONENT_ID + ,CI_FAIL= DECODE(lower(st.CI_FAIL), + 'false', '0', + 'true', '1' + )::integer::boolean + ,HAS_MITIGATIONS=DECODE(lower(st.HAS_MITIGATIONS), + 'false', '0', + 'true', '1' + )::integer::boolean + ,LEVEL_OF_CONFIDENCE=trim(st.LEVEL_OF_CONFIDENCE,'"') ,NOTIFICATION_TYPE=trim(st.NOTIFICATION_TYPE,'"') ,MFA_TYPE=trim(st.MFA_TYPE,'"') ,ACCOUNT_RECOVERY=trim(st.ACCOUNT_RECOVERY,'"') @@ -267,13 +276,13 @@ P Sodhi 15/09/2023 Removed update to the RP table as its not needed. FROM conformed.v_stg_ipv_journey WHERE EVENT_ID IN ( SELECT EVENT_ID - FROM "dap_txma_reporting_db"."conformed"."fact_user_journey_event" + FROM "conformed"."fact_user_journey_event" ) )AS st WHERE fact_user_journey_event.EVENT_ID = st.EVENT_ID; INSERT INTO conformed.FACT_USER_JOURNEY_EVENT (EVENT_KEY,DATE_KEY,verification_route_key,journey_channel_key,relying_party_key,USER_USER_ID, - EVENT_ID,EVENT_TIME,USER_GOVUK_SIGNIN_JOURNEY_ID,COMPONENT_ID,EVENT_COUNT, + EVENT_ID,EVENT_TIME,USER_GOVUK_SIGNIN_JOURNEY_ID,COMPONENT_ID,EVENT_COUNT,CI_FAIL,HAS_MITIGATIONS,LEVEL_OF_CONFIDENCE, REJECTION_REASON,REASON,NOTIFICATION_TYPE,MFA_TYPE,ACCOUNT_RECOVERY,FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL, CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL,ADDRESSES_ENTERED,ACTIVITY_HISTORY_SCORE,IDENTITY_FRAUD_SCORE,DECISION_SCORE, FAILED_CHECK_DETAILS_KBV_RESPONSE_MODE,FAILED_CHECK_DETAILS_CHECK_METHOD,CHECK_DETAILS_KBV_RESPONSE_MODE,CHECK_DETAILS_KBV_QUALITY, @@ -292,6 +301,15 @@ P Sodhi 15/09/2023 Removed update to the RP table as its not needed. ,cnf.user_govuk_signin_journey_id AS USER_GOVUK_SIGNIN_JOURNEY_ID ,cnf.component_id AS COMPONENT_ID ,EVENT_COUNT + , DECODE(lower(CI_FAIL), + 'false', '0', + 'true', '1' + )::integer::boolean + ,DECODE(lower(HAS_MITIGATIONS), + 'false', '0', + 'true', '1' + )::integer::boolean + ,trim(LEVEL_OF_CONFIDENCE,'"') ,trim(REJECTION_REASON,'"') ,trim(REASON,'"') ,trim(NOTIFICATION_TYPE,'"') @@ -392,7 +410,7 @@ P Sodhi 15/09/2023 Removed update to the RP table as its not needed. ON cnf.sub_domain = dvr.verification_route_name; - INSERT into audit.err_duplicate_event_id_ipv_journey_10 (total_duplicate_event_count_minus_one + INSERT into audit.err_duplicate_event_id_ipv_identity_issued_15 (total_duplicate_event_count_minus_one ,product_family,event_name,event_id,timestamp_formatted,created_by,created_datetime) SELECT event_count,Product_family,event_name,event_id,timestamp_formatted,current_user,GETDATE() as Current_date FROM @@ -405,14 +423,14 @@ P Sodhi 15/09/2023 Removed update to the RP table as its not needed. ROW_NUMBER() OVER (PARTITION BY event_id, timestamp_formatted ORDER BY timestamp_formatted) AS row_num, * FROM - "dap_txma_reporting_db"."dap_txma_stage"."ipv_journey" + "dap_txma_stage"."ipv_journey" --where event_id='5c94f844-f05d-4c32-87fe-e3b6b265223f' ) auth - JOIN "dap_txma_reporting_db"."conformed"."batchcontrol" batc ON auth.Product_family = batc.product_family + JOIN "conformed"."batchcontrol" batc ON auth.Product_family = batc.product_family AND auth.processed_date > batc.maxrundate WHERE row_num <> 1 AND (auth.product_family,event_name, event_id) NOT IN (SELECT product_family ,event_name, event_id - FROM audit.err_duplicate_event_id_ipv_journey_10) + FROM audit.err_duplicate_event_id_ipv_identity_issued_15) GROUP BY auth.Product_family, event_name, diff --git a/athena-scripts/redshift_scripts/sp_setup_conformed_schema_statements.sql b/athena-scripts/redshift_scripts/sp_setup_conformed_schema_statements.sql index 7b408d2f1..a62cd2de8 100644 --- a/athena-scripts/redshift_scripts/sp_setup_conformed_schema_statements.sql +++ b/athena-scripts/redshift_scripts/sp_setup_conformed_schema_statements.sql @@ -60,7 +60,8 @@ BEGIN ('IPR_USER_REDIRECTED','IPV_CRI_F2F','IPV','F2F CRI',' '), ('IPV_F2F_CRI_VC_CONSUMED','IPV_CRI_F2F','IPV','F2F CRI',' '), ('IPV_F2F_CRI_VC_RECEIVED','IPV_CRI_F2F','IPV','F2F CRI',' '), - ('F2F_YOTI_RESPONSE_RECEIVED','IPV_CRI_F2F','IPV','F2F CRI',' '); + ('F2F_YOTI_RESPONSE_RECEIVED','IPV_CRI_F2F','IPV','F2F CRI',' '), + ('IPV_IDENTITY_ISSUED','IPV_JOURNEY','IPV','IPV Journey',' '); -- diff --git a/redshift-scripts/setup_process/alter_fact_user_journey_event_iii.sql b/redshift-scripts/setup_process/alter_fact_user_journey_event_iii.sql new file mode 100644 index 000000000..0461810be --- /dev/null +++ b/redshift-scripts/setup_process/alter_fact_user_journey_event_iii.sql @@ -0,0 +1,9 @@ +ALTER TABLE "conformed"."fact_user_journey_event" +ADD COLUMN CI_FAIL BOOLEAN default NULL; + +ALTER TABLE "conformed"."fact_user_journey_event" +ADD COLUMN HAS_MITIGATIONS BOOLEAN default NULL; + + +ALTER TABLE "conformed"."fact_user_journey_event" +ADD COLUMN LEVEL_OF_CONFIDENCE VARCHAR(100) default NULL; \ No newline at end of file diff --git a/redshift-scripts/setup_process/create_err_duplicate_event_id_ipv_identity_issued_15.sql b/redshift-scripts/setup_process/create_err_duplicate_event_id_ipv_identity_issued_15.sql new file mode 100644 index 000000000..369924b78 --- /dev/null +++ b/redshift-scripts/setup_process/create_err_duplicate_event_id_ipv_identity_issued_15.sql @@ -0,0 +1,9 @@ +CREATE TABLE audit.err_duplicate_event_id_ipv_identity_issued_15 ( + product_family character varying(100) ENCODE lzo, + total_duplicate_event_count_minus_one integer ENCODE az64, + event_name character varying(1000) ENCODE lzo, + event_id character varying(1000) ENCODE lzo, + timestamp_formatted character varying(100) ENCODE lzo, + created_by character varying(100) ENCODE lzo, + created_datetime date ENCODE az64 +) DISTSTYLE AUTO; \ No newline at end of file diff --git a/redshift-scripts/setup_process/redshift_setup_process_scripts.sql b/redshift-scripts/setup_process/redshift_setup_process_scripts.sql index d3d3c1f5d..f1074ba45 100644 --- a/redshift-scripts/setup_process/redshift_setup_process_scripts.sql +++ b/redshift-scripts/setup_process/redshift_setup_process_scripts.sql @@ -175,6 +175,22 @@ copy the contents of the files: for each click [Run] button to create the stored procedure: +/****IPV_IDENTITY_ISSUED + +1.alter_fact_user_journey_event_iii.sql +2.ref_events_insert_iii.sql(check this is added to main file) +3.create_err_duplicate_event_id_ipv_identity_issued_15.sql +4.v_stg_ipv_journey_ipv_identity_issued_temp.sql +5.sp_ipv_journey_ipv_identity_issued_temp.sql + +--Update the daily file +6.v_stg_ipv_journey_update.sql -- Update the daily view +7.sp_ipv_journey_ipv_identity_issued_update.sql - update the daily proc + + +**/ + + /* Database object privileges to group diff --git a/redshift-scripts/setup_process/ref_events.sql b/redshift-scripts/setup_process/ref_events.sql index 851c6bdc3..0f2417cc5 100644 --- a/redshift-scripts/setup_process/ref_events.sql +++ b/redshift-scripts/setup_process/ref_events.sql @@ -37,3 +37,7 @@ INSERT INTO conformed.REF_EVENTS VALUES('IPV_F2F_CRI_VC_CONSUMED','IPV_CRI_F2F', INSERT INTO conformed.REF_EVENTS VALUES('IPV_F2F_CRI_VC_RECEIVED','IPV_CRI_F2F','IPV','F2F CRI',' '); INSERT INTO conformed.REF_EVENTS VALUES('F2F_YOTI_RESPONSE_RECEIVED','IPV_CRI_F2F','IPV','F2F CRI',' '); +--SOLO_IPV_IDENTITY_ISSUED +INSERT INTO conformed.REF_EVENTS VALUES('IPV_IDENTITY_ISSUED','IPV_JOURNEY','IPV','IPV Journey',' '); + + diff --git a/redshift-scripts/setup_process/sp_conformed_stage_view_data_objects.sql b/redshift-scripts/setup_process/sp_conformed_stage_view_data_objects.sql index af31a4540..5f54c41b4 100644 --- a/redshift-scripts/setup_process/sp_conformed_stage_view_data_objects.sql +++ b/redshift-scripts/setup_process/sp_conformed_stage_view_data_objects.sql @@ -945,6 +945,9 @@ P Sodhi 15/09/2023 Update to ipv_cri_kbv view. 1 EVENT_COUNT, extensions_rejectionreason REJECTION_REASON, extensions_reason REASON, + extensions_hasmitigations HAS_mitigations, + extensions_levelofconfidence LEVEL_OF_CONFIDENCE, + extensions_cifail CI_FAIL, null NOTIFICATION_TYPE, null MFA_TYPE, null ACCOUNT_RECOVERY, diff --git a/redshift-scripts/setup_process/sp_ipv_journey_ipv_identity_issued_temp.sql b/redshift-scripts/setup_process/sp_ipv_journey_ipv_identity_issued_temp.sql new file mode 100644 index 000000000..bba292cc3 --- /dev/null +++ b/redshift-scripts/setup_process/sp_ipv_journey_ipv_identity_issued_temp.sql @@ -0,0 +1,387 @@ +CREATE OR replace PROCEDURE conformed.sp_ipv_journey_ipv_identity_issued_temp () +AS $$ +BEGIN + +UPDATE conformed.DIM_EVENT +SET + EVENT_NAME = st.EVENT_NAME, + EVENT_DESCRIPTION = st.EVENT_NAME, + PRODUCT_FAMILY=REF_PRODUCT_FAMILY, + EVENT_JOURNEY_TYPE = st.domain, + SERVICE_NAME = st.sub_domain, + MODIFIED_BY=current_user, + MODIFIED_DATE=CURRENT_DATE, + BATCH_ID=0000 +FROM ( + SELECT * + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp + WHERE EVENT_NAME IN ( + SELECT EVENT_NAME + FROM conformed.DIM_EVENT + ) +) AS st +WHERE DIM_EVENT.EVENT_NAME = st.event_name; + + +-- Insert new records into the dimension table +INSERT INTO conformed.DIM_EVENT ( EVENT_NAME, EVENT_DESCRIPTION, PRODUCT_FAMILY ,EVENT_JOURNEY_TYPE, SERVICE_NAME, CREATED_BY, CREATED_DATE, MODIFIED_BY, MODIFIED_DATE,BATCH_ID) +SELECT DISTINCT EVENT_NAME, EVENT_NAME, REF_PRODUCT_FAMILY ,domain, sub_domain,current_user,CURRENT_DATE,current_user, CURRENT_DATE,9999 +FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp +WHERE EVENT_NAME NOT IN (SELECT EVENT_NAME FROM conformed.DIM_EVENT); + + +----DIM_JOURNEY_CHANNEL + +UPDATE conformed.DIM_JOURNEY_CHANNEL +SET + CHANNEL_NAME = CASE + WHEN EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END, + CHANNEL_DESCRIPTION = CASE + WHEN EVENT_NAME LIKE '%IPV%' THEN 'Event has taken place via Web channel' + WHEN EVENT_NAME LIKE '%DCMAW%' THEN 'Event has taken place via App channel' + ELSE 'General - This is the default channel' + END, + MODIFIED_BY=current_user, + MODIFIED_DATE=CURRENT_DATE, + BATCH_ID=0000 +FROM ( + SELECT DISTINCT EVENT_NAME + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp +) AS st +WHERE ( + CASE + WHEN st.EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN st.EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END +) = conformed.DIM_JOURNEY_CHANNEL.CHANNEL_NAME +AND ( + CASE + WHEN st.EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN st.EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END +) IN ( + SELECT CHANNEL_NAME + FROM conformed.DIM_JOURNEY_CHANNEL +); + + +INSERT INTO conformed.DIM_JOURNEY_CHANNEL (CHANNEL_NAME, CHANNEL_DESCRIPTION, CREATED_BY, CREATED_DATE, MODIFIED_BY, MODIFIED_DATE, BATCH_ID) +SELECT DISTINCT CASE + WHEN EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END, + CASE + WHEN EVENT_NAME LIKE '%IPV%' THEN 'Event has taken place via Web channel' + WHEN EVENT_NAME LIKE '%DCMAW%' THEN 'Event has taken place via App channel' + ELSE 'General - This is the default channel' + END, + current_user, + CURRENT_DATE, + current_user, + CURRENT_DATE, + 9999 +FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp AS st +WHERE (CASE + WHEN st.EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN st.EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END) NOT IN ( + SELECT CHANNEL_NAME + FROM conformed.DIM_JOURNEY_CHANNEL + ); + + + ----Insert and update for dim_relying_party + + +-- do not chnage the where clause as redshift doesn’t likes it!!! +/*UPDATE conformed.DIM_RELYING_PARTY +SET + CLIENT_ID = NVL(st.CLIENT_ID,'-1'), + RELYING_PARTY_NAME = st.CLIENT_NAME, + RELYING_PARTY_DESCRIPTION = st.CLIENT_NAME, + MODIFIED_BY= current_user, + MODIFIED_DATE=CURRENT_DATE, + BATCH_ID=0000 +FROM ( + select DISTINCT + mn.CLIENT_ID, + ref.CLIENT_NAME, + current_user, + CURRENT_DATE, + current_user, + CURRENT_DATE, + 9999 + FROM conformed.v_stg_ipv_cri_cic mn + left join "conformed"."ref_relying_parties" ref + on mn.CLIENT_ID=ref.CLIENT_ID +) AS st +WHERE st.CLIENT_NAME=conformed.DIM_RELYING_PARTY.RELYING_PARTY_NAME +and st.CLIENT_ID IN ( + SELECT CLIENT_ID + FROM conformed.DIM_RELYING_PARTY +);*/ + + + + + INSERT INTO conformed.DIM_RELYING_PARTY (CLIENT_ID, RELYING_PARTY_NAME, DISPLAY_NAME, CREATED_BY, CREATED_DATE, MODIFIED_BY, MODIFIED_DATE, BATCH_ID) + SELECT + NVL(st.CLIENT_ID,'-1') , + st.CLIENT_NAME, + st.DISPLAY_NAME, + current_user, + CURRENT_DATE, + current_user, + CURRENT_DATE, + 9999 + FROM ( select DISTINCT + mn.CLIENT_ID , + ref.CLIENT_NAME, + ref.DISPLAY_NAME, + current_user, + CURRENT_DATE, + current_user, + CURRENT_DATE, + 9999 + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp mn + left join "dap_txma_reporting_db"."conformed"."ref_relying_parties" ref + --on mn.CLIENT_ID=ref.CLIENT_ID) AS st + on NVL(mn.CLIENT_ID,'-1') = NVL(ref.CLIENT_ID,'-1') ) AS st + WHERE NVL(st.CLIENT_ID,'-1') NOT IN ( + SELECT NVL(CLIENT_ID,'-1') + FROM conformed.DIM_RELYING_PARTY + ); + + + -- DIM_VERIFICATION_ROUTE insert and update + +UPDATE conformed.DIM_VERIFICATION_ROUTE +SET + VERIFICATION_ROUTE_NAME = st.sub_domain, + VERIFICATION_SHORT_NAME = st.sub_domain, + ROUTE_DESCRIPTION = st.DOMAIN, + MODIFIED_BY= current_user, + MODIFIED_DATE=CURRENT_DATE, + BATCH_ID=0000 +FROM ( + SELECT DISTINCT DOMAIN, sub_domain + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp + WHERE sub_domain IN ( + SELECT VERIFICATION_ROUTE_NAME + FROM conformed.DIM_VERIFICATION_ROUTE + ) +) AS st +WHERE st.sub_domain = conformed.DIM_VERIFICATION_ROUTE.VERIFICATION_ROUTE_NAME; + + +INSERT INTO conformed.DIM_VERIFICATION_ROUTE ( VERIFICATION_ROUTE_NAME, VERIFICATION_SHORT_NAME, ROUTE_DESCRIPTION, CREATED_BY, CREATED_DATE, MODIFIED_BY, MODIFIED_DATE,BATCH_ID) +SELECT DISTINCT sub_domain, sub_domain, domain,current_user,CURRENT_DATE,current_user, CURRENT_DATE,9999 +FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp +WHERE sub_domain NOT IN (SELECT VERIFICATION_ROUTE_NAME FROM conformed.DIM_VERIFICATION_ROUTE); + + + + +UPDATE "conformed"."fact_user_journey_event" +SET + REJECTION_REASON=trim(st.REJECTION_REASON,'"') + ,REASON=trim(st.REASON,'"') + ,USER_USER_ID=st.user_user_id + ,user_govuk_signin_journey_id=st.user_govuk_signin_journey_id + ,COMPONENT_ID=st.COMPONENT_ID + ,CI_FAIL= DECODE(lower(st.CI_FAIL), + 'false', '0', + 'true', '1' + )::integer::boolean + ,HAS_MITIGATIONS=DECODE(lower(st.HAS_MITIGATIONS), + 'false', '0', + 'true', '1' + )::integer::boolean + ,LEVEL_OF_CONFIDENCE=trim(st.LEVEL_OF_CONFIDENCE,'"') + ,NOTIFICATION_TYPE=trim(st.NOTIFICATION_TYPE,'"') + ,MFA_TYPE=trim(st.MFA_TYPE,'"') + ,ACCOUNT_RECOVERY=trim(st.ACCOUNT_RECOVERY,'"') + ,strength_Score=null + ,successful=null + ,DRIVING_PERMIT=null + ,ID_CARD=null + ,PASSPORT=null + ,RESIDENCE_PERMIT=null + ,PREVIOUS_GOVUK_SIGNIN_JOURNEY_ID=null + ,CHECK_DETAILS_PHOTO_VERIFICATION_PROCESS_LEVEL=null + ,FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL=null + ,CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL=null + ,ADDRESSES_ENTERED=trim(st.ADDRESSES_ENTERED ,'"') + ,ACTIVITY_HISTORY_SCORE=Null + ,IDENTITY_FRAUD_SCORE= null + ,DECISION_SCORE= Null + ,FAILED_CHECK_DETAILS_KBV_RESPONSE_MODE=Null + ,FAILED_CHECK_DETAILS_CHECK_METHOD=null + ,CHECK_DETAILS_KBV_RESPONSE_MODE=null + ,CHECK_DETAILS_KBV_QUALITY=null + ,VERIFICATION_SCORE=null + ,CHECK_DETAILS_CHECK_METHOD=null + ,Iss=st.Iss + ,VALIDITY_SCORE=null + ,"TYPE"=null + ,is_new_account= null + ,PROCESSED_DATE=st.PROCESSED_DATE + ,MODIFIED_BY=current_user + ,MODIFIED_DATE=CURRENT_DATE + ,BATCH_ID=0000 +FROM (SELECT * + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp + WHERE EVENT_ID IN ( + SELECT EVENT_ID + FROM "conformed"."fact_user_journey_event" +) )AS st +WHERE fact_user_journey_event.EVENT_ID = st.EVENT_ID; + + +INSERT INTO conformed.FACT_USER_JOURNEY_EVENT (EVENT_KEY,DATE_KEY,verification_route_key,journey_channel_key,relying_party_key,USER_USER_ID, + EVENT_ID,EVENT_TIME,user_govuk_signin_journey_id,COMPONENT_ID,EVENT_COUNT,CI_FAIL,HAS_MITIGATIONS,LEVEL_OF_CONFIDENCE, + REJECTION_REASON,REASON,NOTIFICATION_TYPE,MFA_TYPE,ACCOUNT_RECOVERY,FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL, + CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL,CHECK_DETAILS_PHOTO_VERIFICATION_PROCESS_LEVEL, + ADDRESSES_ENTERED,ACTIVITY_HISTORY_SCORE,IDENTITY_FRAUD_SCORE,DECISION_SCORE, + FAILED_CHECK_DETAILS_KBV_RESPONSE_MODE,FAILED_CHECK_DETAILS_CHECK_METHOD,CHECK_DETAILS_KBV_RESPONSE_MODE,CHECK_DETAILS_KBV_QUALITY, + VERIFICATION_SCORE,CHECK_DETAILS_CHECK_METHOD,Iss,VALIDITY_SCORE,"TYPE",is_new_account, strength_Score,successful, + PROCESSED_DATE,DRIVING_PERMIT,ID_CARD,PASSPORT,RESIDENCE_PERMIT,PREVIOUS_GOVUK_SIGNIN_JOURNEY_ID, + CREATED_BY, CREATED_DATE, MODIFIED_BY, MODIFIED_DATE, BATCH_ID) +SELECT NVL(DE.event_key,-1) AS event_key + ,dd.date_key + ,NVL(dvr.verification_route_key,-1) AS verification_route_key + , NVL(djc.journey_channel_key,-1) AS journey_channel_key + , NVL(drp.relying_party_key,-1) AS relying_party_key + ,user_user_id AS USER_USER_ID + ,event_id AS EVENT_ID + --,cnf.event_name + --,cnf.timestamp AS EVENT_TIME + ,cnf.timestamp_formatted as EVENT_TIME + ,cnf.user_govuk_signin_journey_id AS user_govuk_signin_journey_id + ,cnf.component_id AS COMPONENT_ID + ,EVENT_COUNT + , DECODE(lower(CI_FAIL), + 'false', '0', + 'true', '1' + )::integer::boolean + ,DECODE(lower(HAS_MITIGATIONS), + 'false', '0', + 'true', '1' + )::integer::boolean + ,trim(LEVEL_OF_CONFIDENCE,'"') + ,trim(REJECTION_REASON,'"') + ,trim(REASON,'"') + ,trim(NOTIFICATION_TYPE,'"') + ,trim(MFA_TYPE,'"') + ,trim(ACCOUNT_RECOVERY,'"') + --,FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL + ,null FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL + --,CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL + ,null CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL + ,null checkdetails_photo_verification_process_level + --,ADDRESSES_ENTERED + ,trim(ADDRESSES_ENTERED ,'"') + --,ACTIVITY_HISTORY_SCORE + ,null ACTIVITY_HISTORY_SCORE + ,null IDENTITY_FRAUD_SCORE + --,null + ,null DECISION_SCORE + --,null + ,FAILED_CHECK_DETAILS_KBV_RESPONSE_MODE + --,null + ,null FAILED_CHECK_DETAILS_CHECK_METHOD + --,null + ,CHECK_DETAILS_KBV_RESPONSE_MODEL + --,null + ,CHECK_DETAILS_KBV_QUALITY + --,null + --,VERIFICATION_SCORE + ,null VERIFICATION_SCORE + --,CHECK_DETAILS_CHECK_METHOD + ,null CHECK_DETAILS_CHECK_METHOD + ,Iss + --,VALIDITY_SCORE + ,null VALIDITY_SCORE + --,"TYPE" + ,null "TYPE" + ,null is_new_account + ,null strength_Score + ,null successful + ,PROCESSED_DATE + ,null restricted_drivingpermit + ,null restricted_idcard + ,null restricted_passport + ,null restricted_residencepermit + ,null extensions_previousgovuksigninjourneyid + ,current_user + , CURRENT_DATE + ,current_user + , CURRENT_DATE + , 9999 +FROM (SELECT * + FROM conformed.v_stg_ipv_journey_ipv_identity_issued_temp + WHERE EVENT_ID NOT IN ( + SELECT EVENT_ID + FROM conformed.FACT_USER_JOURNEY_EVENT) + --and event_id='68d7215e-36cc-4f6d-b409-da445bb5f0aa' + )cnf +JOIN conformed.dim_date dd ON date(cnf.timestamp_formatted)= dd.date +LEFT JOIN conformed.DIM_EVENT DE ON cnf.event_name = DE.EVENT_NAME +LEFT JOIN conformed.dim_journey_channel djc ON + (CASE + WHEN cnf.EVENT_NAME LIKE '%IPV%' THEN 'Web' + WHEN cnf.EVENT_NAME LIKE '%DCMAW%' THEN 'App' + ELSE 'General' + END) = djc.channel_name +LEFT JOIN conformed.dim_relying_party drp ON +cnf.CLIENT_ID = drp.CLIENT_ID +LEFT JOIN conformed.dim_verification_route dvr + ON cnf.sub_domain = dvr.verification_route_name; + + + INSERT into audit.err_duplicate_event_id_ipv_identity_issued_15 (total_duplicate_event_count_minus_one + ,product_family,event_name,event_id,timestamp_formatted,created_by,created_datetime) +SELECT event_count,Product_family,event_name,event_id,timestamp_formatted,current_user,GETDATE() as Current_date + FROM + ( + SELECT COUNT(*) AS event_count,event_name,auth.Product_family,event_id,timestamp_formatted + FROM + ( + SELECT + 'ipv_identity_issued' AS Product_family, + ROW_NUMBER() OVER (PARTITION BY event_id, timestamp_formatted ORDER BY timestamp_formatted) AS row_num, + * + FROM + "dap_txma_stage"."ipv_journey" + WHERE lower(event_name) in ('ipv_identity_issued') + --where event_id='5c94f844-f05d-4c32-87fe-e3b6b265223f' + ) auth + JOIN "conformed"."batchcontrol" batc ON auth.Product_family = batc.product_family + AND auth.processed_date > batc.maxrundate + WHERE row_num <> 1 + AND (auth.product_family,event_name, event_id) NOT IN (SELECT product_family ,event_name, event_id + FROM audit.err_duplicate_event_id_ipv_identity_issued_15) + GROUP BY + auth.Product_family, + event_name, + event_id, + timestamp_formatted + ) subquery; + + + + raise info 'processing of product family: ipv_journey_ipv_identity_issued ran successfully'; + + EXCEPTION WHEN OTHERS THEN + RAISE EXCEPTION '[error while processing product family: ipv_journey_ipv_identity_issued] exception: %',sqlerrm; + +END; + +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/redshift-scripts/setup_process/v_stg_ipv_journey_ipv_identity_issued_temp.sql b/redshift-scripts/setup_process/v_stg_ipv_journey_ipv_identity_issued_temp.sql new file mode 100644 index 000000000..844fa2af0 --- /dev/null +++ b/redshift-scripts/setup_process/v_stg_ipv_journey_ipv_identity_issued_temp.sql @@ -0,0 +1,60 @@ +Create or replace view conformed.v_stg_ipv_journey_ipv_identity_issued_temp +AS +select DISTINCT +Auth.product_family, +Auth.event_id, +Auth.client_id, +Auth.component_id, +Auth.user_govuk_signin_journey_id, +Auth.user_user_id, +Auth.timestamp, +Auth.timestamp_formatted, +null extensions_clientname, +Auth.processed_date, +Auth.event_name, +1 EVENT_COUNT, +extensions_hasmitigations HAS_mitigations, +extensions_levelofconfidence LEVEL_OF_CONFIDENCE, +extensions_cifail CI_FAIL, +Null REJECTION_REASON, +Null REASON, +Null NOTIFICATION_TYPE, +Null MFA_TYPE, +Null ACCOUNT_RECOVERY, +Null FAILED_CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL, +Null CHECK_DETAILS_BIOMETRIC_VERIFICATION_PROCESS_LEVEL, +Null ADDRESSES_ENTERED, +Null ACTIVITY_HISTORY_SCORE, +Null IDENTITY_FRAUD_SCORE, +Null DECISION_SCORE, +Null FAILED_CHECK_DETAILS_KBV_RESPONSE_MODE, +Null FAILED_CHECK_DETAILS_CHECK_METHOD, +Null CHECK_DETAILS_KBV_RESPONSE_MODEL, +Null CHECK_DETAILS_KBV_QUALITY, +Null VERIFICATION_SCORE, +Null CHECK_DETAILS_CHECK_METHOD, +Null Iss, +Null VALIDITY_SCORE, +Null "TYPE", +BatC.product_family batch_product_family, +BatC.maxrundate, +ref.product_family ref_product_family, +ref.domain, +ref.sub_domain, +ref.other_sub_domain from +( select * from + (SELECT + 'ipv_journey' Product_family + ,row_number() over (partition by event_id,timestamp_formatted order by cast (day as integer) desc) as row_num,* + FROM + "dap_txma_stage"."ipv_journey" + WHERE lower(event_name) in ('ipv_identity_issued') + ) + where row_num=1 + ) Auth + join conformed.BatchControl BatC + On Auth.Product_family=BatC.Product_family + and to_date(processed_date,'YYYYMMDD') > '19990101' + join conformed.REF_EVENTS ref + on Auth.EVENT_NAME=ref.event_name + with no schema binding;