2025-06-19 13:16:41 +08:00

165 lines
12 KiB
SQL

-- play_tag_ltv play_tag_amount_ltv
WITH ga AS (
SELECT
id,
name,
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 play_tag,
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) / 100 AS pay_amount
FROM public.ods_payment_order
WHERE status = 1
AND ds::date BETWEEN '${startdate}' AND '${bizdate}'
GROUP BY appid, ds, user_id
),
na AS (
SELECT
ds,
appid,
user_id
FROM public.ods_newly_account
WHERE 1=1
AND ds::date BETWEEN '${startdate}' AND '${bizdate}'
),
base_data AS (SELECT
na.ds::date AS cohort_date,
na.appid,
ga.name AS appname,
tg.play_tag,
tg.ver_tag,
tg.value_tag,
tg.job_tag,
tg.feature_tag,
na.user_id,
po.pay_amount,
po.ds::date - na.ds::date AS n_day
FROM na
INNER JOIN
ga ON na.appid = ga.id
LEFT JOIN
po ON na.appid = po.appid AND na.user_id = po.user_id AND po.ds::date BETWEEN na.ds::date AND na.ds::date + 120
LEFT JOIN
tg ON ga.bind_game_id = tg.game_id)
INSERT INTO
datasci.ads_996eco_index_ltv_m (index_type,data_month,play_tag,acc_count,ltv0,ltv1,ltv2,ltv3,ltv4,ltv5,ltv6,ltv7,ltv8,ltv9,ltv10,ltv11,ltv12,ltv13,ltv14,ltv15,ltv16,ltv17,ltv18,ltv19,ltv20,ltv21,ltv22,ltv23,ltv24,ltv25,ltv26,ltv27,ltv28,ltv29,ltv30,ltv31,ltv45,ltv60,ltv90,ltv120)
SELECT
'play_tag_amount_ltv' index_type,
TO_CHAR(DATE_TRUNC('month', cohort_date), 'YYYY-MM') AS data_month,
appid,
play_tag,
-- appname,
UNIQ(user_id) AS new_cnt,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 0 AND n_day <= 0 THEN pay_amount ELSE NULL END) AS ltv0,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 1 AND n_day <= 1 THEN pay_amount ELSE NULL END) AS ltv1,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 2 AND n_day <= 2 THEN pay_amount ELSE NULL END) AS ltv2,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 3 AND n_day <= 3 THEN pay_amount ELSE NULL END) AS ltv3,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 4 AND n_day <= 4 THEN pay_amount ELSE NULL END) AS ltv4,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 5 AND n_day <= 5 THEN pay_amount ELSE NULL END) AS ltv5,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 6 AND n_day <= 6 THEN pay_amount ELSE NULL END) AS ltv6,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 7 AND n_day <= 7 THEN pay_amount ELSE NULL END) AS ltv7,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 8 AND n_day <= 8 THEN pay_amount ELSE NULL END) AS ltv8,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 9 AND n_day <= 9 THEN pay_amount ELSE NULL END) AS ltv9,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 10 AND n_day <= 10 THEN pay_amount ELSE NULL END) AS ltv10,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 11 AND n_day <= 11 THEN pay_amount ELSE NULL END) AS ltv11,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 12 AND n_day <= 12 THEN pay_amount ELSE NULL END) AS ltv12,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 13 AND n_day <= 13 THEN pay_amount ELSE NULL END) AS ltv13,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 14 AND n_day <= 14 THEN pay_amount ELSE NULL END) AS ltv14,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 15 AND n_day <= 15 THEN pay_amount ELSE NULL END) AS ltv15,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 16 AND n_day <= 16 THEN pay_amount ELSE NULL END) AS ltv16,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 17 AND n_day <= 17 THEN pay_amount ELSE NULL END) AS ltv17,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 18 AND n_day <= 18 THEN pay_amount ELSE NULL END) AS ltv18,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 19 AND n_day <= 19 THEN pay_amount ELSE NULL END) AS ltv19,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 20 AND n_day <= 20 THEN pay_amount ELSE NULL END) AS ltv20,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 21 AND n_day <= 21 THEN pay_amount ELSE NULL END) AS ltv21,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 22 AND n_day <= 22 THEN pay_amount ELSE NULL END) AS ltv22,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 23 AND n_day <= 23 THEN pay_amount ELSE NULL END) AS ltv23,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 24 AND n_day <= 24 THEN pay_amount ELSE NULL END) AS ltv24,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 25 AND n_day <= 25 THEN pay_amount ELSE NULL END) AS ltv25,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 26 AND n_day <= 26 THEN pay_amount ELSE NULL END) AS ltv26,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 27 AND n_day <= 27 THEN pay_amount ELSE NULL END) AS ltv27,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 28 AND n_day <= 28 THEN pay_amount ELSE NULL END) AS ltv28,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 29 AND n_day <= 29 THEN pay_amount ELSE NULL END) AS ltv29,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 30 AND n_day <= 30 THEN pay_amount ELSE NULL END) AS ltv30,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 31 AND n_day <= 31 THEN pay_amount ELSE NULL END) AS ltv31,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 45 AND n_day <= 45 THEN pay_amount ELSE NULL END) AS ltv45,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 60 AND n_day <= 60 THEN pay_amount ELSE NULL END) AS ltv60,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 90 AND n_day <= 90 THEN pay_amount ELSE NULL END) AS ltv90,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 120 AND n_day <= 120 THEN pay_amount ELSE NULL END) AS ltv120
FROM base_data
WHERE play_tag IS NOT NULL
GROUP BY GROUPING SETS((data_month, appid, play_tag), (appid, play_tag))
UNION ALL
SELECT
'play_tag_ltv' index_type,
TO_CHAR(DATE_TRUNC('month', cohort_date), 'YYYY-MM') AS data_month,
appid,
play_tag,
-- appname,
UNIQ(user_id) AS new_cnt,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 0 AND n_day <= 0 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv0,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 1 AND n_day <= 1 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv1,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 2 AND n_day <= 2 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv2,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 3 AND n_day <= 3 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv3,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 4 AND n_day <= 4 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv4,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 5 AND n_day <= 5 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv5,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 6 AND n_day <= 6 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv6,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 7 AND n_day <= 7 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv7,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 8 AND n_day <= 8 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv8,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 9 AND n_day <= 9 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv9,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 10 AND n_day <= 10 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv10,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 11 AND n_day <= 11 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv11,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 12 AND n_day <= 12 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv12,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 13 AND n_day <= 13 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv13,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 14 AND n_day <= 14 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv14,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 15 AND n_day <= 15 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv15,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 16 AND n_day <= 16 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv16,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 17 AND n_day <= 17 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv17,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 18 AND n_day <= 18 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv18,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 19 AND n_day <= 19 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv19,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 20 AND n_day <= 20 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv20,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 21 AND n_day <= 21 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv21,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 22 AND n_day <= 22 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv22,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 23 AND n_day <= 23 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv23,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 24 AND n_day <= 24 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv24,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 25 AND n_day <= 25 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv25,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 26 AND n_day <= 26 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv26,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 27 AND n_day <= 27 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv27,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 28 AND n_day <= 28 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv28,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 29 AND n_day <= 29 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv29,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 30 AND n_day <= 30 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv30,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 31 AND n_day <= 31 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv31,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 45 AND n_day <= 45 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv45,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 60 AND n_day <= 60 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv60,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 90 AND n_day <= 90 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv90,
SUM(CASE WHEN CURRENT_DATE - cohort_date - 1 >= 120 AND n_day <= 120 THEN pay_amount ELSE NULL END)::numeric / UNIQ(user_id)::numeric AS ltv120
FROM base_data
WHERE play_tag IS NOT NULL
GROUP BY GROUPING SETS((data_month, appid, play_tag), (appid, play_tag))
;