diff --git a/996eco/1.sql b/996eco/1.sql new file mode 100644 index 0000000..566b6fc --- /dev/null +++ b/996eco/1.sql @@ -0,0 +1,97 @@ +with retention_new_acc as +( + select + appid,app_name,channel,bind_game_id, + event_time,user_id,ds::date as new_acc_dt + from + ( + select + bind_game_id,appid,app_name,channel,event_time,user_id,ds,row_number() over(partition by user_id order by event_time asc) as rn + from + ( + select + appid,gm.name as app_name,channel,event_time,user_id,ds,gm.bind_game_id + from public.ods_newly_account acc + inner join + ( + select id,name,bind_game_id + from public.gm_apply + where bind_game_type=1 + ) gm on acc.appid=gm.id + ) t + ) t1 + where rn=1 + and ds between '${hisdate}' and '${bizdate}' + --and user_id='1419067566' +), +retention_active_detail as +( + select + ds::date as dt,user_id + 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 + where t1.ds>='${hisdate}' and t1.ds<=to_char(dateadd('${bizdate}'::date,31,'dd'),'yyyymmdd') + group by + ds::date,user_id +), +retention_rd as +( + select + appid,app_name,channel,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, + event_time,t1.user_id,new_acc_dt,t2.dt as act_dt,t2.dt-t1.new_acc_dt as rd + from retention_new_acc t1 + left join retention_active_detail t2 on t1.user_id=t2.user_id + left outer join + (select game_id,tag from public.game_tags where tag in ('神器','复古','沉默','火龙','合击','迷失','小极品','大极品','二合一','铭文','冰雪','宠物','战神','暗黑','元素','忘忧','BUFF','天罡'))tg_play + on t1.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 t1.bind_game_id=tg_ver.game_id + left outer join + (select game_id,tag from public.game_tags where tag in ('经典','微变','中变','超变'))tg_value + on t1.bind_game_id=tg_value.game_id + left outer join + (select game_id,tag from public.game_tags where tag in ('单职业','三职业','多职业'))tg_job + on t1.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 t1.bind_game_id=tg_feature.game_id + where t2.dt-t1.new_acc_dt in (0,1,7,14,30,60,90,180) + --t1.user_id='1419067566' +) + +select + t1.tg_play,t1.tg_ver,t1.tg_value,t1.tg_job,t1.tg_feature,t1.new_acc_mon,t1.new_user_num,t2.ret_1,ret_7,ret_14,ret_30,ret_60,ret_90,ret_180 +from +( + select + coalesce(tg_play,'未知') as tg_play,coalesce(tg_ver,'未知') as tg_ver,coalesce(tg_value,'未知') as tg_value,coalesce(tg_job,'未知') as tg_job,coalesce(tg_feature,'未知') as tg_feature, + date_trunc('month',new_acc_dt) as new_acc_mon,uniq(user_id) as new_user_num + from retention_rd + where rd=0 + group by + coalesce(tg_play,'未知') ,coalesce(tg_ver,'未知') ,coalesce(tg_value,'未知') ,coalesce(tg_job,'未知') ,coalesce(tg_feature,'未知'),date_trunc('month',new_acc_dt) +) t1 +left join +( + select + coalesce(tg_play,'未知') as tg_play,coalesce(tg_ver,'未知') as tg_ver,coalesce(tg_value,'未知') as tg_value,coalesce(tg_job,'未知') as tg_job, + coalesce(tg_feature,'未知') as tg_feature,date_trunc('month',new_acc_dt) as new_acc_mon, + uniq(case when rd=1 then user_id else null end) as ret_1, + uniq(case when rd=7 then user_id else null end) as ret_7, + uniq(case when rd=14 then user_id else null end) as ret_14, + uniq(case when rd=30 then user_id else null end) as ret_30, + uniq(case when rd=60 then user_id else null end) as ret_60, + uniq(case when rd=90 then user_id else null end) as ret_90, + uniq(case when rd=180 then user_id else null end) as ret_180 + from retention_rd + where rd>0 + group by + coalesce(tg_play,'未知') ,coalesce(tg_ver,'未知') ,coalesce(tg_value,'未知') ,coalesce(tg_job,'未知') ,coalesce(tg_feature,'未知'),date_trunc('month',new_acc_dt) +) t2 on t1.new_acc_mon=t2.new_acc_mon and t1.tg_play=t2.tg_play and t1.tg_ver=t2.tg_ver and t1.tg_value=t2.tg_value and t1.tg_job=t2.tg_job and t1.tg_feature=t2.tg_feature +limit 10000 \ No newline at end of file diff --git a/996eco/2.sql b/996eco/2.sql new file mode 100644 index 0000000..003ff23 --- /dev/null +++ b/996eco/2.sql @@ -0,0 +1,31 @@ +-- 也优化不了 +select to_char(to_timestamp(event_time_min), 'YYYY-MM') as reg_month, + DATE_TRUNC('month', to_timestamp(event_time_min)) as reg_month_date, + case when tg_play.tag is null then '未知' else tg_play.tag end as play_tag, + 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 -- 默认应用 +) 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 +group by 1, 2, 3 limit 10000 \ No newline at end of file diff --git a/996eco/ads_996eco_index_ltv_m.sql b/996eco/ads_996eco_index_ltv_m.sql index 0ab1f39..7a66a7d 100644 --- a/996eco/ads_996eco_index_ltv_m.sql +++ b/996eco/ads_996eco_index_ltv_m.sql @@ -1,54 +1,7 @@ - CREATE TABLE datasci.ads_996eco_index_ltv_m ( - index_type text, - data_month text, - is_box text, - re_device_type text, - appid text, - coop text, - play_tag text, - avg_new bigint, - acc_count bigint, - ltv0 bigint, - ltv1 bigint, - ltv2 bigint, - ltv3 bigint, - ltv4 bigint, - ltv5 bigint, - ltv6 bigint, - ltv7 bigint, - ltv8 bigint, - ltv9 bigint, - ltv10 bigint, - ltv11 bigint, - ltv12 bigint, - ltv13 bigint, - ltv14 bigint, - ltv15 bigint, - ltv16 bigint, - ltv17 bigint, - ltv18 bigint, - ltv19 bigint, - ltv20 bigint, - ltv21 bigint, - ltv22 bigint, - ltv23 bigint, - ltv24 bigint, - ltv25 bigint, - ltv26 bigint, - ltv27 bigint, - ltv28 bigint, - ltv29 bigint, - ltv30 bigint, - ltv31 bigint, - ltv45 bigint, - ltv60 bigint, - ltv90 bigint, - ltv120 bigint -); - DELETE FROM datasci.ads_996eco_index_ltv_m WHERE 1=1; --------------------- +-- 从24年1月到现在 数据量无法做增量 +-------------------- 1 --LTV WITH ga AS ( SELECT @@ -150,6 +103,7 @@ GROUP BY appid, re_device_type ; -------------------- +-- 从24年1月到现在 数据量无法做增量 @@ -312,7 +266,7 @@ WHERE acc_count > 100 -- 此处是随便拍的一个避免新增人数过少导 GROUP BY 1, 2, 3; -------------------- - +-- 可以优化 with retention_new_acc as ( select @@ -682,7 +636,7 @@ left join ; -------------------- - +-- 可以优化 with retention_new_acc as ( select @@ -1066,6 +1020,7 @@ left join ; -------------------- +-- 从24年10月到现在 数据量无法做增量 with retention_new_acc as (