From d7406d6d602f16b9de0de7729e55f3bd25737b78 Mon Sep 17 00:00:00 2001 From: root <root@64792e78fd4d> Date: Wed, 18 Sep 2024 17:45:38 +0800 Subject: [PATCH] =?UTF-8?q?add=20workflow=20=E6=B3=B0=E5=85=8BCRM,dev?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../客户联系方式映射/cust_contact_mapping.sql | 36 ++++ .../cust_contact_mapping_agi.sql | 155 ++++++++++++++++++ 2 files changed, 191 insertions(+) create mode 100644 dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping.sql create mode 100644 dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping_agi.sql diff --git a/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping.sql b/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping.sql new file mode 100644 index 0000000..6c1c80a --- /dev/null +++ b/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping.sql @@ -0,0 +1,36 @@ + +DROP TABLE IF EXISTS p30_common.cust_contact_mapping; +CREATE TABLE IF NOT EXISTS p30_common.cust_contact_mapping ( + contact_id VARCHAR(50) + , user_id VARCHAR(50) + , crm_contact text + , scrm_contact text + , livechat_contact text + , udesk_contact text + , ccc_contact text + , src_sysname VARCHAR(50) + , src_table VARCHAR(50) + , etl_job VARCHAR(50) + , etl_first_dt timestamp(0) + , etl_proc_dt timestamp(0) + , etl_tx_dt DATE + , etl_batch_no VARCHAR(50) + ,primary key( contact_id ) +); + + COMMENT ON COLUMN p30_common.cust_contact_mapping.contact_id IS '联系编号'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.user_id IS '用户信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.crm_contact IS 'CRM信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.scrm_contact IS 'SCRM信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.livechat_contact IS 'Livechat客户信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.udesk_contact IS 'Udesk客户信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.ccc_contact IS 'ccc客户信息'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.src_sysname IS '来源系统'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.src_table IS '来源表'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.etl_job IS '作业名称'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.etl_first_dt IS '最初入库时间'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.etl_proc_dt IS '本次入库时间'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.etl_tx_dt IS '作业运行时间'; + COMMENT ON COLUMN p30_common.cust_contact_mapping.etl_batch_no IS '作业批次号'; + +COMMENT ON TABLE p30_common.cust_contact_mapping IS '客户联系方式映射'; \ No newline at end of file diff --git a/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping_agi.sql b/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping_agi.sql new file mode 100644 index 0000000..2f3a2d2 --- /dev/null +++ b/dev/workflow/TK_Cust/tk_crm/客户联系方式映射/cust_contact_mapping_agi.sql @@ -0,0 +1,155 @@ +/***************************************************************************************************/ +/*script in Sql, generate by SdmCreateScript 2020(by Qihang Feng, QF255001@TERADATA.COM) */ +/*VERSION 01.10 revised on 2020-08-25 */ +/*Brilliance stems from wisdoms. */ +/*************Head Section**************************************************************************/ +/*Script Use: Periodically load data to :cust_contact_mapping(客户联系方式映射) */ +/*Create Date:2024-09-18 17:42:09 */ +/*SDM Developed By: dev */ +/*SDM Developed Date: 2024-01-19 */ +/*SDM Checked By: dev */ +/*SDM Checked Date: 2024-09-18 */ +/*Script Developed By: dev */ +/*Script Checked By: dev */ +/*Source table 1: p30_common.d_scrm_contact */ +/*Source table 2: :COMMDB.cust_contact_mapping */ +/*Job Type: Inbound transform (Tier 1 to Tier 2) */ +/*Target Table:cust_contact_mapping */ +/*ETL Job Name:cust_contact_mapping */ +/*ETL Frequency:Daily */ +/*ETL Policy:F1 */ +/********************************************************************************************/ +/*******Main Section**************************************************************************/ +\set ON_ERROR_STOP on +\set AUTOCOMMIT on +\timing on + + + +/*创建临时表加载当前数据 */ +CREATE TEMPORARY TABLE cust_contact_mapping_agi_CUR_I + ( LIKE :COMMDB.cust_contact_mapping) +ON COMMIT PRESERVE ROWS; + + +/*****************************************************************************************************/ +/* GROUP 1:Source Table:d_scrm_contact****************************************************************/ +/*****************************************************************************************************/ + +INSERT INTO cust_contact_mapping_agi_CUR_I ( + contact_id /*联系编号*/ + ,user_id /*用户信息*/ + ,crm_contact /*CRM信息*/ + ,scrm_contact /*SCRM信息*/ + ,livechat_contact /*Livechat客户信息*/ + ,udesk_contact /*Udesk客户信息*/ + ,ccc_contact /*ccc客户信息*/ + ,src_sysname /*来源系统*/ + ,src_table /*来源表*/ + ,etl_job /*作业名称*/ + ,etl_first_dt /*最初入库时间*/ + ,etl_proc_dt /*本次入库时间*/ + ,etl_tx_dt /*作业运行时间*/ + ,etl_batch_no /*作业批次号*/ + ) +SELECT + coalesce(p1.contact_id,'LCON-'||lpad(nextval('p20_pdm.user_id_seq')::text,10,'0')) /*contact_id*/ + ,p0.user_id /*user_id*/ + ,p0.crm_contact /*crm_contact*/ + ,p0.scrm_contact /*scrm_contact*/ + ,p0.livechat_contact /*livechat_contact*/ + ,p0.udesk_contact /*udesk_contact*/ + ,p0.ccc_contact /*ccc_contact*/ + ,Substr('d_scrm_contact',1,3) /*src_sysname*/ + ,'d_scrm_contact' /*src_table*/ + ,:ETLJOB /*etl_job*/ + ,TO_DATE(:TXDATE,'YYYYMMDD') /*etl_first_dt*/ + ,current_timestamp(0) /*etl_proc_dt*/ + ,TO_DATE(:TXDATE,'YYYYMMDD') /*etl_tx_dt*/ + ,0 /*etl_batch_no*/ + +FROM (select '' contact_id,user_id +,string_agg(case when src_channel='CRM' then crm_contact_account else '' end,',') crm_contact +,string_agg(case when src_channel='SCRM' then crm_contact_account else '' end,',') scrm_contact +,string_agg(case when src_channel='Livechat' then crm_contact_account else '' end,',') livechat_contact +,string_agg(case when src_channel='Udesk' then crm_contact_account else '' end,',') udesk_contact +,string_agg(case when src_channel='SMART CCC' then crm_contact_account else '' end,',') ccc_contact +from ( +select case when tel ~ '^1[3-9]\d{9}$' then tel + when email ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9.-]+.[a-zA-Z]{2,4}$' then email + else name + end user_id,id crm_contact_account,'SMART CCC' src_channel from p30_common.d_ccc_cust_info +union all +select case when mobile_phone ~ '^1[3-9]\d{9}$' then mobile_phone + when email ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9.-]+.[a-zA-Z]{2,4}$' then email + else full_name + end user_id,crm_contact_account,'CRM' src_channel from p30_common.d_crm_contact +union all +select case when mobile_phone ~ '^1[3-9]\d{9}$' then mobile_phone + when email ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9.-]+.[a-zA-Z]{2,4}$' then email + when length(wechat_id) >5 then wechat_id + else full_name + end user_id,scrm_leads_id,'SCRM' from p30_common.d_scrm_contact +union all +select case when mobile_phone ~ '^1[3-9]\d{9}$' then mobile_phone + when email ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9.-]+.[a-zA-Z]{2,4}$' then email + else full_name + end user_id,livechat_leads_id,'Livechat' from p30_common.d_livechat_contact +union all +select case when mobile_phone ~ '^1[3-9]\d{9}$' then mobile_phone + else full_name + end user_id,udesk_contact,'Udesk' from p30_common.d_udesk_contact)p1 +group by user_id) p0 +LEFT JOIN :COMMDB.cust_contact_mapping p1 + ON p1.user_id=p0 .user_id + + +; + + + +/*从目标表中删除所有数据 cust_contact_mapping(客户联系方式映射) */ +DELETE FROM :COMMDB.cust_contact_mapping +WHERE ETL_JOB=:ETLJOB; + + +/*将新增数据插入到目标表 */ +;INSERT INTO :COMMDB.cust_contact_mapping ( + user_id /*用户信息*/ + ,crm_contact /*CRM信息*/ + ,scrm_contact /*SCRM信息*/ + ,livechat_contact /*Livechat客户信息*/ + ,udesk_contact /*Udesk客户信息*/ + ,ccc_contact /*ccc客户信息*/ + ,contact_id /*联系编号*/ + ,src_sysname /*来源系统*/ + ,src_table /*来源表*/ + ,etl_job /*作业名称*/ + ,etl_first_dt /*最初入库时间*/ + ,etl_proc_dt /*本次入库时间*/ + ,etl_tx_dt /*作业运行时间*/ + ,etl_batch_no /*作业批次号*/ + + ) + SELECT + P1.user_id /*用户信息*/ + ,P1.crm_contact /*CRM信息*/ + ,P1.scrm_contact /*SCRM信息*/ + ,P1.livechat_contact /*Livechat客户信息*/ + ,P1.udesk_contact /*Udesk客户信息*/ + ,P1.ccc_contact /*ccc客户信息*/ + ,P1.contact_id /*联系编号*/ + ,P1.src_sysname /*来源系统*/ + ,P1.src_table /*来源表*/ + ,P1.etl_job /*作业名称*/ + ,P1.etl_first_dt /*最初入库时间*/ + ,P1.etl_proc_dt /*本次入库时间*/ + ,P1.etl_tx_dt /*作业运行时间*/ + ,P1.etl_batch_no /*作业批次号*/ + + FROM cust_contact_mapping_agi_CUR_I P1 + +; +/*****程序结束退出 */ +\q +