CREATE TABLE datasci.ads_996eco_index_role_m ( index_type text, data_month text, tg_play text, tg_ver text, tg_value text, tg_job text, tg_feature text, act_num bigint, acc_count bigint, pay_cnt bigint, pay_amount bigint, ); DELETE FROM datasci.ads_996eco_index_channel_m WHERE ds = '${month}'; INSERT INTO datasci.ads_996eco_index_role_m (index_type,data_month,tg_play,tg_ver,tg_value,tg_job,tg_feature,act_num) select 'mau' index_type, '${month}' AS data_month, tg_play.tag as tg_play,tg_ver.tag as tg_ver,tg_value.tag as tg_value,tg_job.tag as tg_job,tg_feature.tag as tg_feature, uniq(user_id) as act_num from public.ods_active_account t1 inner join ( select id,name,bind_game_id from public.gm_apply where bind_game_type=1 ) t2 on t1.appid=t2.id left outer join (select game_id,tag from public.game_tags where tag in ('神器','复古','沉默','火龙','合击','迷失','小极品','大极品','二合一','铭文','冰雪','宠物','战神','暗黑','元素','忘忧','BUFF','天罡'))tg_play on t2.bind_game_id=tg_play.game_id left outer join (select game_id,tag from public.game_tags where tag in ('1.70','1.76','1.80','1.85','1.95'))tg_ver on t2.bind_game_id=tg_ver.game_id left outer join (select game_id,tag from public.game_tags where tag in ('经典','微变','中变','超变'))tg_value on t2.bind_game_id=tg_value.game_id left outer join (select game_id,tag from public.game_tags where tag in ('单职业','三职业','多职业'))tg_job on t2.bind_game_id=tg_job.game_id left outer join (select game_id,tag from public.game_tags where tag in ('3D','开服1年','开服2年','开服3年','开服4年'))tg_feature on t2.bind_game_id=tg_feature.game_id where t1.ds BETWEEN '${hisdate}' AND '${bizdate}' group by 1,2,3,4,5,6,7 ; -- reg INSERT INTO datasci.ads_996eco_index_role_m (index_type,data_month,tg_play,acc_count) select 'reg' index_type, '${month}' AS data_month, case when tg_play.tag is null then '未知' else tg_play.tag end as tg_play, uniq(mi.user_id) as acc_count from public.ods_newly_account acc inner join (select user_id,min(event_time) as event_time_min from public.ods_newly_account acc inner join (select * from public.gm_apply WHERE bind_game_type = 1 -- 传奇游戏 ) app on acc.appid=app.id group by user_id ) mi ---从玩家的众多游戏记录中选取最早的一条 on acc.user_id=mi.user_id and acc.event_time=mi.event_time_min inner join (SELECT id as app_id, name as app_name, bind_game_id, bind_game_type ---1 :传奇游戏 , 2:传世 , 3:传3 FROM public.gm_apply WHERE bind_type = 1 -- 默认应用 -- AND bind_game_type = 1 -- 传奇游戏 ) gm on acc.appid=gm.app_id left outer join (select game_id,tag from public.game_tags where tag in ('神器','复古','沉默','火龙','合击','迷失','小极品','大极品','二合一','铭文','冰雪','宠物','战神','暗黑','元素','忘忧','BUFF','天罡'))tg_play on gm.bind_game_id=tg_play.game_id where acc.ds BETWEEN '${hisdate}' AND '${bizdate}' group by 1,2,3 ; --付费人数和金额 WITH ga AS ( SELECT id, bind_game_id FROM public.gm_apply WHERE bind_type = 1 AND bind_game_type = 1 ), tg AS ( SELECT game_id, string_agg(DISTINCT CASE WHEN tag in ('神器','复古','沉默','火龙','合击','迷失','小极品','大极品','二合一','铭文','冰雪','宠物','战神','暗黑','元素','忘忧','BUFF','天罡') THEN tag ELSE NULL END,',') AS tg_play, string_agg(DISTINCT CASE WHEN tag in ('1.70','1.76','1.80','1.85','1.95')THEN tag ELSE NULL END, ',') AS ver_tag, string_agg(DISTINCT CASE WHEN tag in ('经典','微变','中变','超变') THEN tag ELSE NULL END,',') AS value_tag, string_agg(DISTINCT CASE WHEN tag in ('单职业','三职业','多职业') THEN tag ELSE NULL END,',') AS job_tag, string_agg(DISTINCT CASE WHEN tag in ('3D','开服1年','开服2年','开服3年','开服4年') THEN tag ELSE NULL END,',') AS feature_tag FROM public.game_tags GROUP BY game_id ), po AS ( SELECT appid, ds, user_id, SUM(amount) AS pay_amount FROM public.ods_payment_order WHERE status = 1 AND ds::date BETWEEN '${hisdate}' AND '${bizdate}' GROUP BY 1, 2, 3 ) INSERT INTO datasci.ads_996eco_index_role_m (index_type,data_month,tg_play,pay_cnt,pay_amount) SELECT 'pay' index_type, '${month}' AS data_month, tg.tg_play, UNIQ(po.user_id) AS pay_cnt, SUM(po.pay_amount) AS pay_amount FROM po INNER JOIN ga ON po.appid = ga.id LEFT JOIN tg ON ga.bind_game_id = tg.game_id GROUP BY 1,2,3 ; --月活跃人数 WITH ga AS ( SELECT id, bind_game_id FROM public.gm_apply WHERE bind_type = 1 AND bind_game_type = 1 ), tg AS ( SELECT game_id, string_agg(DISTINCT CASE WHEN tag in ('神器','复古','沉默','火龙','合击','迷失','小极品','大极品','二合一','铭文','冰雪','宠物','战神','暗黑','元素','忘忧','BUFF','天罡') THEN tag ELSE NULL END,',') AS tg_play, string_agg(DISTINCT CASE WHEN tag in ('1.70','1.76','1.80','1.85','1.95')THEN tag ELSE NULL END, ',') AS ver_tag, string_agg(DISTINCT CASE WHEN tag in ('经典','微变','中变','超变') THEN tag ELSE NULL END,',') AS value_tag, string_agg(DISTINCT CASE WHEN tag in ('单职业','三职业','多职业') THEN tag ELSE NULL END,',') AS job_tag, string_agg(DISTINCT CASE WHEN tag in ('3D','开服1年','开服2年','开服3年','开服4年') THEN tag ELSE NULL END,',') AS feature_tag FROM public.game_tags GROUP BY game_id ), aa AS ( SELECT appid, ds, user_id FROM public.ods_active_account WHERE ds BETWEEN '${hisdate}' AND '${bizdate}' GROUP BY 1, 2, 3 ) INSERT INTO datasci.ads_996eco_index_role_m (index_type,data_month,tg_play,acc_count) SELECT 'tg-mau' index_type, '${month}' AS data_month, tg.tg_play, UNIQ(aa.user_id) AS acc_count FROM aa INNER JOIN ga ON aa.appid = ga.id LEFT JOIN tg ON ga.bind_game_id = tg.game_id GROUP BY 1,2,3 ;