add workflow 泰克客户,dev
This commit is contained in:
parent
25c009c0b7
commit
198afc0047
|
@ -0,0 +1,18 @@
|
|||
|
||||
DROP TABLE IF EXISTS p30_common.cust_contact_mapping;
|
||||
CREATE TABLE IF NOT EXISTS p30_common.cust_contact_mapping (
|
||||
contact_id text
|
||||
, user_id text
|
||||
, crm_contact text
|
||||
, scrm_contact text
|
||||
, livechat_contact text
|
||||
|
||||
);
|
||||
|
||||
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 '';
|
||||
COMMENT ON COLUMN p30_common.cust_contact_mapping.scrm_contact IS '';
|
||||
COMMENT ON COLUMN p30_common.cust_contact_mapping.livechat_contact IS '';
|
||||
|
||||
COMMENT ON TABLE p30_common.cust_contact_mapping IS '';
|
|
@ -0,0 +1,144 @@
|
|||
/***************************************************************************************************/
|
||||
/*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-05-06 15:12:25 */
|
||||
/*SDM Developed By: dev */
|
||||
/*SDM Developed Date: 2024-01-19 */
|
||||
/*SDM Checked By: dev */
|
||||
/*SDM Checked Date: 2024-05-06 */
|
||||
/*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客户信息*/
|
||||
,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('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*/
|
||||
,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
|
||||
from (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客户信息*/
|
||||
,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.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
|
||||
|
|
@ -188,6 +188,14 @@ params={'my_param':"d_livechat_contact_agi"},
|
|||
depends_on_past=False,
|
||||
retries=3,
|
||||
dag=dag)
|
||||
cust_contact_mapping = SSHOperator(
|
||||
ssh_hook=sshHook,
|
||||
task_id='cust_contact_mapping',
|
||||
command='/data/airflow/etl/COM/run_psql.sh {{ ds_nodash }} {{params.my_param}} >>/data/airflow/logs/run_tpt_{{ds_nodash}}.log 2>&1 ',
|
||||
params={'my_param':"cust_contact_mapping_agi"},
|
||||
depends_on_past=False,
|
||||
retries=3,
|
||||
dag=dag)
|
||||
file_Tk01 >> livechat_6381
|
||||
file_Udesk_record >> udesk_record_3768
|
||||
file_CRM_Raw_Leads >> crm_raw_leads_6024
|
||||
|
@ -200,4 +208,6 @@ china_city_4536 >> t00_china_city_info
|
|||
udesk_record_3768 >> t01_udesk_record
|
||||
t01_udesk_record >> d_udesk_contact
|
||||
t01_livechat_record >> d_livechat_contact
|
||||
d_livechat_contact >> task_failed
|
||||
d_udesk_contact >> cust_contact_mapping
|
||||
d_livechat_contact >> cust_contact_mapping
|
||||
cust_contact_mapping >> task_failed
|
||||
|
|
Loading…
Reference in New Issue