-- 由于收入是按照不同的统计方式选择不同的计算方式
-- 1.divide_type=1:
--   order_amount * divide_scale
-- 2.divide_type=2:
--     阶梯(累计):
--     0->10% 50->20% 100->%30
--     第一个月20(流水): 20->10%
--     第二个月90(流水): 30->10% 50->20% 10->30%
-- 3.divide_type=3:
-- 阶梯(按月):
--     0->10% 50->20% 100->%30
--     第一个月20(流水): 20->10%
--     第二个月90(流水): 50->10% 40->20%
WITH money_divide_scale_tmp AS (
SELECT
        relation_id,
        money,
        divide_scale,
        COALESCE(LEAD(money) OVER (PARTITION BY relation_id ORDER BY money), 999999999999.99) AS next_money
    FROM (

            SELECT
                relation_id,
                cast((elem->>'money')::text as numeric) money,
                cast((elem->>'divide_scale')::text as numeric) divide_scale
            FROM (
                SELECT
                    relation_id,
                    jsonb_array_elements(divide_scale_step) elem
                FROM
                    dim.game_product_relation
                WHERE
                    divide_type != 1
              ) tt

) ttt
WHERE
ttt.money IS NOT NULL
AND ttt.divide_scale IS NOT NULL
),
revenue_df_tmp AS
(
-- divide_type=1 money= order_amount * divide_scale
SELECT
    t2.relation_id,
    SUM(t1.order_amount * t2.divide_scale)
    money,
    t1.ds,
    t1.ds_type,
    t1.ds_name
FROM
    dwd.order_df t1
    INNER JOIN dim.game_product_relation t2 ON t1.game_channel_id = t2.game_channel_id
    AND t1.game_identity = t2.game_identity
    AND t1.game_platform_id = t2.game_platform_id
    AND t2.divide_type = 1
    where t1.ds_type = 'd'
GROUP BY
    t2.relation_id,
    t1.ds,
    t1.ds_type,
    t1.ds_name
UNION ALL
-- 阶梯(累计):
-- 0->10% 50->20% 100->%30
-- 第一个月20(流水): 20->10%
-- 第二个月90(流水): 30->10% 50->20% 10->30%
SELECT
    tt1.relation_id,
    tt1.order_amount * tt2.divide_scale  money,
    tt1.ds,
    tt1.ds_type,
    tt1.ds_name
FROM (
    SELECT
        t2.relation_id,
        t1.ds,
        t1.ds_type,
        t1.ds_name,
        t1.order_amount,
        SUM(t1.order_amount) OVER (PARTITION BY t2.relation_id ORDER BY ds) AS sum_order_amount
    FROM
        dwd.order_df t1
        INNER JOIN dim.game_product_relation t2 ON t1.game_channel_id = t2.game_channel_id
            AND t1.game_identity = t2.game_identity
            AND t1.game_platform_id = t2.game_platform_id
            AND t2.divide_type = 2
    WHERE
        t1.ds_type = 'd') tt1
    INNER JOIN money_divide_scale_tmp tt2 ON tt1.relation_id = tt2.relation_id
        AND tt1.sum_order_amount >= tt2.money
        AND tt1.sum_order_amount <= tt2.next_money
-- 阶梯(按月):
-- 0->10% 50->20% 100->%30
-- 第一个月20(流水): 20->10%
-- 第二个月90(流水): 50->10% 40->20%
-- divide_type=3
UNION ALL
SELECT
    tt1.relation_id,
    tt1.order_amount * tt2.divide_scale  money,
    tt1.ds,
    tt1.ds_type,
    tt1.ds_name
FROM (
    SELECT
        t2.relation_id,
        t1.ds,
        t1.ds_type,
        t1.ds_name,
        t1.order_amount,
        SUM(t1.order_amount) OVER (PARTITION BY t2.relation_id, SUBSTR(t1.ds, 1, 6) ORDER BY ds) AS sum_order_amount
    FROM
        dwd.order_df t1
    INNER JOIN dim.game_product_relation t2 ON t1.game_channel_id = t2.game_channel_id
        AND t1.game_identity = t2.game_identity
        AND t1.game_platform_id = t2.game_platform_id
        AND t2.divide_type = 3
WHERE
    t1.ds_type = 'd') tt1
INNER JOIN money_divide_scale_tmp tt2 ON tt1.relation_id = tt2.relation_id
    AND tt1.sum_order_amount >= tt2.money
    AND tt1.sum_order_amount <= tt2.next_money

)
INSERT INTO dwd.revenue_df(relation_id,money,ds,ds_type,ds_name)
SELECT  relation_id
        ,sum(money) money
        ,ds
        ,ds_type
        ,ds_name
FROM    revenue_df_tmp where relation_id='${relation_id}'
GROUP BY relation_id
         ,ds
         ,ds_type
         ,ds_name
union all
SELECT  relation_id
        ,sum(money) money
        ,SUBSTRING(ds, 1, 6) || '00' ds
        ,'m' ds_type
        ,'月' ds_name
FROM    revenue_df_tmp where relation_id='${relation_id}'
GROUP BY relation_id
         ,SUBSTRING(ds, 1, 6) || '00'
ON CONFLICT (relation_id,ds,ds_type)
DO UPDATE SET money = EXCLUDED.money,ds_name = EXCLUDED.ds_name
;