langjiu-project/FineReport/财务主题/看板/资金管理驾驶舱.sql

1472 lines
61 KiB
SQL

-- ======================================
-- 表格-现金收入情况-收入类型【已核对】
-- ======================================
WITH base_date AS
(SELECT
stat_date
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售酒类回款' THEN amt ELSE 0 END) / 10000 AS wine_amt -- 酒类回款
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售非酒类回款' THEN amt ELSE 0 END) / 10000 AS nowine_amt -- 非酒类回款
,SUM(CASE WHEN trade_direction = '收入' THEN amt ELSE 0 END) / 10000 AS amt -- 合计
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")}
AND trade_direction = '收入'
AND indi_type = '执行'
AND plan_item_name IN('对外销售酒类回款','对外销售非酒类回款')
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY stat_date
)
SELECT
-- 当月
SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN wine_amt ELSE 0 END) AS wine_amt_m -- 当月对外销售酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN nowine_amt ELSE 0 END) AS nowine_amt_m -- 当月对外销售非酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_m -- 当月合计
-- 当年
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN wine_amt ELSE 0 END) AS wine_amt_y -- 当年对外销售酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN nowine_amt ELSE 0 END) AS nowine_amt_y -- 当年对外销售非酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_y -- 当年合计
-- 去年当月
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN wine_amt ELSE 0 END) AS wine_amt_last_m -- 去年当月对外销售酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN nowine_amt ELSE 0 END) AS nowine_amt_last_m -- 去年当月对外销售非酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_last_m -- 去年当月合计
-- 去年
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN wine_amt ELSE 0 END) AS wine_amt_last_y -- 去年对外销售酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN nowine_amt ELSE 0 END) AS nowine_amt_last_y -- 去年对外销售非酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_last_y -- 去年合计
FROM base_date
;
-- ======================================
-- 表格-现金支出情况-【已核对】
-- ======================================
WITH base_date AS(
select
plan_item_name
,stat_date
,SUM(CASE WHEN trade_direction = '支出' THEN amt ELSE 0 END) / 10000 AS amt
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
AND trade_direction = '支出'
AND indi_type = '执行'
AND plan_item_name NOT IN ('内部调拨支出','偿还贷款')
AND owner_bank_account <> '22195101040012008'
${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY plan_item_name,stat_date
)
SELECT
plan_item_name
-- 当月
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_m -- 当月支出金额
-- 去年当月
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_last_m -- 去年当月支出金额
-- 当年
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_y -- 当年支出金额
-- 去年
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_last_y -- 去年支出金额
FROM base_date
GROUP BY plan_item_name
ORDER BY SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) DESC
;
-- ======================================
-- 表格-资金余额情况-【已验证】
-- ======================================
WITH base_data AS(
SELECT amt_type
, stat_date
, SUM(CASE WHEN nvl(a.is_usable, 1) = 1 THEN amt ELSE 0 END) / 10000 AS amt
FROM dm.dm_fim_fud_balance a
LEFT JOIN dwr.dim_corp c ON a.corp_code = c.corp_code
LEFT JOIN dwr.dim_bank_account dba ON DECODE(LENGTH(a.owner_bank_account), 17,
SUBSTRING(a.owner_bank_account, 3),
a.owner_bank_account) =
DECODE(LENGTH(dba.accountnumber), '17',
SUBSTRING(dba.accountnumber, 3),
dba.accountnumber)
AND dba.account_owner_class = 'langjiu'
WHERE a.corp_code NOT IN ('0101', '0103', '0102')
AND nvl(a.is_usable, 1) = 1
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
-- AND if(dba.accountnumber IN ('20351059900100000512291', '22195101040012008', '信用证保证金'),
-- '保证金户', category_name) <> '保证金户'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY amt_type, stat_date
UNION ALL
SELECT '冻结资金' AS amt_type
, stat_date
, SUM(CASE WHEN nvl(a.is_usable, 1) = 1 THEN amt ELSE 0 END) / 10000 AS amt
FROM dm.dm_fim_fud_balance a
LEFT JOIN dwr.dim_corp c ON a.corp_code = c.corp_code
LEFT JOIN dwr.dim_bank_account dba ON DECODE(LENGTH(a.owner_bank_account), 17,
SUBSTRING(a.owner_bank_account, 3),
a.owner_bank_account) =
DECODE(LENGTH(dba.accountnumber), '17',
SUBSTRING(dba.accountnumber, 3),
dba.accountnumber)
AND dba.account_owner_class = 'langjiu'
WHERE a.corp_code NOT IN ('0101', '0103', '0102')
AND nvl(a.is_usable, 0) = 0
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
-- AND if(dba.accountnumber IN ('20351059900100000512291', '22195101040012008', '信用证保证金'),
-- '保证金户', category_name) <> '保证金户'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY stat_date
)
SELECT
-- 当月
SUM(CASE WHEN amt_type = '现金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS cash_amt_m -- 当月现金余额
,SUM(CASE WHEN amt_type = '票据' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS bill_amt_m -- 当月票据余额
,SUM(CASE WHEN amt_type = '冻结资金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS frozen_amt_m -- 当月冻结资金
-- 当年
,SUM(CASE WHEN amt_type = '现金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS cash_amt_y -- 当年现金余额
,SUM(CASE WHEN amt_type = '票据' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS bill_amt_y -- 当年票据余额
,SUM(CASE WHEN amt_type = '冻结资金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
THEN amt ELSE 0 END) AS frozen_amt_y -- 当年冻结资金
-- 去年当月
,SUM(CASE WHEN amt_type = '现金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS cash_amt_last_m -- 去年当月现金余额
,SUM(CASE WHEN amt_type = '票据' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS bill_amt_last_m -- 去年当月票据余额
,SUM(CASE WHEN amt_type = '冻结资金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS frozen_amt_last_m -- 去年当月冻结资金
-- 去年
,SUM(CASE WHEN amt_type = '现金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS cash_amt_last_y -- 去年现金余额
,SUM(CASE WHEN amt_type = '票据' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS bill_amt_last_y -- 去年票据余额
,SUM(CASE WHEN amt_type = '冻结资金' AND to_char(stat_date,'yyyy-MM') = '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM")}'
THEN amt ELSE 0 END) AS frozen_amt_last_y -- 去年冻结资金
FROM base_data
;
-- ======================================
-- 表格-融资-手工填写
-- ======================================
-- ======================================
-- 图表-资金收支存总览
-- ======================================
-- 【图表_资金收支总览收入支出】
-- 银行收支
with day_amt as (
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_bank_account_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")}
AND to_char(trade_time,'yyyy-MM-dd') = '${sStart_date}'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
union all
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_draft_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND to_char(trade_time,'yyyy-MM-dd') = '${sStart_date}'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
),
m_y_amt AS (
SELECT
stat_date
,SUM(CASE WHEN trade_direction = '收入' THEN amt ELSE 0 END) / 10000 AS amt_in
,SUM(CASE WHEN trade_direction = '支出' THEN amt ELSE 0 END) / 10000 AS amt_out
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
AND trade_direction IN('收入','支出')
AND indi_type = '执行'
AND plan_item_name NOT IN ('内部调拨收入','取得贷款','内部调拨支出','偿还贷款')
AND owner_bank_account <> '22195101040012008'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY stat_date
)
SELECT
SUM(today_in_amt) AS today_in_amt -- 今日收入
,SUM(today_out_amt) AS today_out_amt -- 今日支出
,SUM(year_in_amt) AS year_in_amt -- 年收入
,SUM(year_out_amt) AS year_out_amt -- 年度支出
,SUM(month_in_amt) AS month_in_amt -- 月收入
,SUM(month_out_amt) AS month_out_amt -- 月支出
FROM
(
select
SUM(CASE WHEN trade_direction = '收入' AND plan_item_name NOT IN ('内部调拨收入','取得贷款') THEN amt ELSE 0 END ) / 10000 AS today_in_amt -- 今日收入
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name NOT IN ('内部调拨支出','偿还贷款') THEN amt ELSE 0 END ) / 10000 AS today_out_amt -- 今日支出
,0 AS year_in_amt -- 年收入
,0 AS year_out_amt -- 年度支出
,0 AS month_in_amt -- 月收入
,0 AS month_out_amt -- 月支出
FROM day_amt
WHERE trade_direction IN('收入','支出')
UNION ALL
SELECT
0 AS today_in_amt -- 今日收入
,0 AS today_out_amt -- 今日支出
,SUM(amt_in) AS year_in_amt -- 年收入
,SUM(amt_out) AS year_out_amt -- 年度支出
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' THEN amt_in ELSE 0 END) AS month_in_amt -- 月收入
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}' THEN amt_out ELSE 0 END) AS month_out_amt -- 月支出
FROM m_y_amt
)T
-- ======================================
-- 资金余额
-- ======================================
-- 【图表_资金收支总览资金】
with base_data AS (
select
0 AS begin_year_amt -- 年初可用资金余额
,SUM(CASE WHEN a.is_usable = 1 THEN a.amt ELSE 0 END ) / 10000 AS amt -- 12月末资金余额
,SUM(CASE WHEN a.create_by = 'xj' AND a.is_usable = 0 THEN a.amt ELSE 0 END ) / 10000 AS sec_amt-- 12月末保证金余额
from dm.dm_fim_fud_balance a
left join dwr.dim_corp c on a.corp_code=c.corp_code
left join dwr.dim_bank_account dba on decode(length(a.owner_bank_account), 17,
substring(a.owner_bank_account, 3),
a.owner_bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
where a.corp_code not in ('0101','0103','0102')
AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
UNION ALL
SELECT
SUM(CASE WHEN a.is_usable = 1 THEN a.amt ELSE 0 END ) / 10000 AS begin_year_amt -- 年初可用资金余额
,0 AS amt -- 12月末资金余额
,0 AS sec_amt-- 12月末保证金余额
from dm.dm_fim_fud_balance a
left join dwr.dim_corp c on a.corp_code=c.corp_code
left join dwr.dim_bank_account dba on decode(length(a.owner_bank_account), 17,
substring(a.owner_bank_account, 3),
a.owner_bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)and dba.account_owner_class='langjiu'
where a.corp_code not in ('0101','0103','0102')
AND to_char(stat_date,'yyyy-MM') = '${FORMAT(MONTHDELTA(DATEINYEAR(sStart_date,1),-1),"yyyy-MM")}'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
)
SELECT
SUM(begin_year_amt) AS begin_year_amt -- 年初可用资金余额
,SUM(amt) AS amt -- 12月末资金余额
,SUM(sec_amt) AS sec_amt -- 12月末保证金余额
FROM base_data
-- ======================================
-- 资金分析_可用资金
-- ======================================
-- 存款类型占比
SELECT amt_type
, SUM(CASE WHEN nvl(a.is_usable, 1) = 1 THEN amt ELSE 0 END) / 10000 AS amt
FROM dm.dm_fim_fud_balance a
WHERE a.corp_code NOT IN ('0101', '0103', '0102')
AND nvl(a.is_usable, 1) = 1
AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY amt_type
ORDER BY amt_type
-- 银行余额分布
SELECT
amt_type
,nvl(dba.bank_name,'未知银行') as bank_name
,SUM(CASE WHEN nvl(a.is_usable, 1) = 1 THEN amt ELSE 0 END) / 10000 AS amt
FROM dm.dm_fim_fud_balance a
left join dwr.dim_bank_account dba
on decode(length(a.owner_bank_account), 17,substring(a.owner_bank_account, 3),
a.owner_bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
WHERE a.corp_code NOT IN ('0101', '0103', '0102')
AND nvl(a.is_usable, 1) = 1
AND to_char(stat_date,'yyyy-MM') = '${FORMAT(sStart_date,"yyyy-MM")}'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY amt_type,nvl(dba.bank_name,'未知银行')
ORDER BY decode('amt_type','票据',1,'现金',2),SUM(CASE WHEN nvl(a.is_usable, 1) = 1 THEN amt ELSE 0 END) DESC
-- ======================================
-- 资金收入
-- ======================================
-- 收入类型
WITH base_date AS
(SELECT
stat_date
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售酒类回款' THEN amt ELSE 0 END) / 10000 AS wine_amt -- 酒类回款
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售非酒类回款' THEN amt ELSE 0 END) / 10000 AS nowine_amt -- 非酒类回款
,SUM(CASE WHEN trade_direction = '收入' THEN amt ELSE 0 END) / 10000 AS amt -- 合计
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")}
AND trade_direction = '收入'
AND indi_type = '执行'
AND plan_item_name IN('对外销售酒类回款','对外销售非酒类回款')
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY stat_date
)
SELECT
-- 当月
SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}'
THEN wine_amt ELSE 0 END) AS wine_amt_m -- 当月对外销售酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}'
THEN nowine_amt ELSE 0 END) AS nowine_amt_m -- 当月对外销售非酒类回款
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}'
THEN amt ELSE 0 END) AS amt_m -- 当月合计
FROM base_date
-- 年度各项目收入
SELECT
plan_item_name
,SUM(CASE WHEN trade_direction = '收入' THEN amt ELSE 0 END) / 10000 AS amt_in
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
AND trade_direction = '收入'
AND indi_type = '执行'
AND plan_item_name NOT IN ('内部调拨收入','取得贷款')
AND owner_bank_account <> '22195101040012008'
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}'
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY plan_item_name
ORDER BY plan_item_name
-- 收入趋势
with re as (
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_bank_account_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
union all
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_draft_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
)
-- 近15天
${if(sData_type=1,"","/*")}
select
to_char(trade_time,'MM-dd') AS trade_time
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name NOT IN ('内部调拨收入','取得贷款') THEN amt ELSE 0 END ) / 10000 AS
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name NOT IN ('内部调拨支出','偿还贷款') THEN amt ELSE 0 END ) / 10000 AS
from re
WHERE trade_direction IN('收入','支出')
AND to_char(trade_time,'yyyy-MM-dd') >= '${FORMAT(DATEDELTA(sStart_date,-15),"yyyy-MM-dd")}'
AND to_char(trade_time,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
GROUP BY to_char(trade_time,'MM-dd')
ORDER BY to_char(trade_time,'MM-dd')
${if(sData_type=1,"","*/")}
-- 近12个月
${if(sData_type=2,"","/*")}
select
to_char(trade_time,'MM') AS trade_time
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name NOT IN ('内部调拨收入','取得贷款') THEN amt ELSE 0 END ) / 10000 AS
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name NOT IN ('内部调拨支出','偿还贷款') THEN amt ELSE 0 END ) / 10000 AS
from re
WHERE trade_direction IN('收入','支出')
AND to_char(trade_time,'yyyy-MM') >= '${FORMAT(MONTHDELTA(sStart_date,-12),"yyyy-MM")}'
AND to_char(trade_time,'yyyy-MM') <= '${FORMAT(sStart_date,"yyyy-MM")}'
GROUP BY to_char(trade_time,'MM')
ORDER BY to_char(trade_time,'MM')
${if(sData_type=2,"","*/")}
-- ======================================
-- 图表-资金支出
-- ======================================
-- 项目支出
WITH base_date AS(
select
plan_item_name
,stat_date
,SUM(CASE WHEN trade_direction = '支出' THEN amt ELSE 0 END) / 10000 AS amt
from dm.dm_fim_fud_indicator a
where corp_code not in ('0101','0103','0102')
AND trade_direction = '支出'
AND indi_type = '执行'
AND plan_item_name NOT IN ('内部调拨支出','偿还贷款')
AND owner_bank_account <> '22195101040012008'
${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
GROUP BY plan_item_name,stat_date
)
SELECT
plan_item_name
-- 当年
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) AS amt_y -- 当年支出金额
FROM base_date
GROUP BY plan_item_name
ORDER BY SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(sStart_date,"yyyy")}' AND to_char(stat_date,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
THEN amt ELSE 0 END) DESC
LIMIT 10
;
-- 支出趋势
with re as (
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_bank_account_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
union all
select
trade_time,
trade_direction,
plan_item_name,
amt
from dm.v_ag_fim_draft_flow a
where trade_time>=date'2021-01-01'
AND owner_bank_account <> '22195101040012008'
AND corp_code not in ('0101','0103','0102')
${IF(LEN(sCorp)!=0," AND a.corp_code IN ('"+ sCorp +"')", "")}
AND exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
OR per_code = a.corp_code -- 事业部
)
)
)
-- 近15天
${if(sData_type_out=1,"","/*")}
select
to_char(trade_time,'MM-dd') AS trade_time
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name NOT IN ('内部调拨收入','取得贷款') THEN amt ELSE 0 END ) / 10000 AS
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name NOT IN ('内部调拨支出','偿还贷款') THEN amt ELSE 0 END ) / 10000 AS
from re
WHERE trade_direction IN('收入','支出')
AND to_char(trade_time,'yyyy-MM-dd') >= '${FORMAT(DATEDELTA(sStart_date,-15),"yyyy-MM-dd")}'
AND to_char(trade_time,'yyyy-MM-dd') <= '${FORMAT(sStart_date,"yyyy-MM-dd")}'
GROUP BY to_char(trade_time,'MM-dd')
ORDER BY to_char(trade_time,'MM-dd')
${if(sData_type_out=1,"","*/")}
-- 近12个月
${if(sData_type_out=2,"","/*")}
select
to_char(trade_time,'MM') AS trade_time
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name NOT IN ('内部调拨收入','取得贷款') THEN amt ELSE 0 END ) / 10000 AS
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name NOT IN ('内部调拨支出','偿还贷款') THEN amt ELSE 0 END ) / 10000 AS
from re
WHERE trade_direction IN('收入','支出')
AND to_char(trade_time,'yyyy-MM') >= '${FORMAT(MONTHDELTA(sStart_date,-12),"yyyy-MM")}'
AND to_char(trade_time,'yyyy-MM') <= '${FORMAT(sStart_date,"yyyy-MM")}'
GROUP BY to_char(trade_time,'MM')
ORDER BY to_char(trade_time,'MM')
${if(sData_type_out=2,"","*/")}
-- ======================================
-- 资金日报
-- ======================================
-- 期初余额 斌哥处理
-- 资金收入/流入
WITH amt_base AS
(
-- 映射日报科目对照关系
SELECT
stat_date -- 统计日期
-- todo:期初余额
-- 其中:可用存款
-- 银行承兑汇票
-- 香港公司账户资金
-- 受限资金
-- 收入
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售酒类回款' AND corp_code <> '0201' THEN amt ELSE 0 END) AS finished_in_amt -- 成品酒销售回款
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name = '对外销售酒类回款' AND corp_code = '0201' THEN amt ELSE 0 END) AS loose_in_amt -- 散酒销售回款
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name in ('保证金','共建基金') THEN amt ELSE 0 END)
+ SUM(CASE WHEN trade_direction = '收入' AND trade_item IN('红包充值费用','转货款') THEN amt ELSE 0 END) AS redpkg_in_amt -- 红包款/转货款/保证金/共建
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name IN('取得贷款','开票') THEN amt ELSE 0 END) AS bank_in_amt -- 银行融资
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name IN('搬迁补偿/政府补助') THEN amt ELSE 0 END) AS compen_in_amt -- 政府补助
,SUM(CASE WHEN trade_direction = '收入' AND plan_item_name IN('对外销售非酒类回款','吸收投资','税费返还','其他收入(含未确认收入)','票据变现收入','利息收入') THEN amt ELSE 0 END)
+ -1 * SUM(CASE WHEN trade_direction = '收入' AND trade_item IN('红包充值费用','转货款') THEN amt ELSE 0 END)
AS other_in_amt -- 其他零星收款
-- 支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('原材料','辅料','低值易耗') THEN amt ELSE 0 END) AS low_mater_out_amt -- 原辅低耗材料
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('散酒') THEN amt ELSE 0 END) AS loose_liquor_out_amt -- 外购散酒
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('外购包材','外协加工费') THEN amt ELSE 0 END) AS outsourced_out_amt -- 外购包材/外协加工
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('其它制造费用','水电气费') THEN amt ELSE 0 END) AS make_out_amt -- 制造费用/能源费用
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('广告费','市场活动投入','其它销售费用','委外服务(庄园)','酒店采购','储运费') THEN amt ELSE 0 END) AS ad_out_amt -- 广告/市场活动/庄园采购/储运
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('退共建基金') THEN amt ELSE 0 END)
+ SUM(CASE WHEN trade_direction = '收入' AND plan_item_name in('票据变现收入') THEN amt ELSE 0 END )
AS build_out_amt -- 共建支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('退经销商货款') THEN amt ELSE 0 END) AS dealer_out_amt -- 经销商退款
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('职工薪酬及福利') THEN amt ELSE 0 END) AS salary_out_amt -- 薪酬及福利
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('税费') THEN amt ELSE 0 END) AS tax_out_amt -- 税金缴纳
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('其它管理费用','财务手续费用','研发费用') THEN amt ELSE 0 END) AS manage_out_amt -- 管理费用/研发费用
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('土地支出') THEN amt ELSE 0 END) AS land_out_amt -- 土地支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('土建支出') THEN amt ELSE 0 END) AS land_build_out_amt -- 土建支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('设备支出','维修支出') THEN amt ELSE 0 END) AS repair_out_amt -- 设备及维修支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('偿还贷款') THEN amt ELSE 0 END) AS repay_out_amt -- 归还贷款
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('利息支出') THEN amt ELSE 0 END) AS interest_out_amt -- 利息支出
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('分配股利') THEN amt ELSE 0 END) AS dividend_out_amt -- 分配股利
,SUM(CASE WHEN trade_direction = '支出' AND plan_item_name in('退保证金','对外捐赠','支付其他代收代付','其他(含未确认支出)','票据变现支出','投资支出') THEN amt ELSE 0 END)
+ -1 * SUM(CASE WHEN trade_direction = '收入' AND plan_item_name in('票据变现收入') THEN amt ELSE 0 END )
AS other_out_amt -- 其他(捐赠等)
-- todo:期末余额
FROM dm.dm_fim_fud_indicator fp
where fp.trade_direction IN('收入','支出')
and fp.indi_type='执行'
AND fp.plan_item_name NOT IN ('内部调拨支出','内部调拨收入')
and EXISTS (
SELECT
1
FROM
dm.dm_bi_user_permisson
WHERE
bi_user = '${fine_username}'
AND per_model IN ('all','fim')
AND (
is_all = 1
OR per_code = fp.corp_code
)
)
AND stat_date >= date '2023-01-01'
GROUP BY stat_date
),amt_base_class AS
(
-- 为方便计算同环比方便,使用扩展方式,而不是计算所有指标
-- 收入
SELECT
stat_date
,'收入' AS fee_class
,'成品酒销售回款' AS fee_type
,finished_in_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'收入' AS fee_class
,'散酒销售回款' as fee_type
,loose_in_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'收入' AS fee_class
,'红包款/转货款/保证金/共建' as fee_type
,redpkg_in_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'收入' AS fee_clas
,'政府补助' as fee_type
,compen_in_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'收入' AS fee_clas
,'银行融资' as fee_type
,bank_in_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'收入' AS fee_class
,'其他零星收款' as fee_type
,other_in_amt AS amt
FROM amt_base
UNION ALL
/*增加资金汇兑损益*/
select date(concat_ws(',',account_year,account_month,'1')) as stat_date
,'收入' AS fee_class
,'其他零星收款' as fee_type
,losses_amt AS amt
from sdi_hzg.exchange_gains_losses
UNION ALL
-- 支出
SELECT
stat_date
,'支出' AS fee_class
,'原辅低耗材料' as fee_type
,low_mater_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'外购散酒' as fee_type
,loose_liquor_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'外购包材/外协加工' as fee_type
,outsourced_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'制造费用/能源费用' as fee_type
,make_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'广告/市场活动/庄园采购/储运' as fee_type
,ad_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'共建支出' as fee_type
,build_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'经销商退款' as fee_type
,dealer_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'薪酬及福利' as fee_type
,salary_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'税金缴纳' as fee_type
,tax_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'管理费用/研发费用' as fee_type
,manage_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'土地支出' as fee_type
,land_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'土建支出' as fee_type
,land_build_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'设备及维修支出' as fee_type
,repair_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'归还贷款' as fee_type
,repay_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'利息支出' as fee_type
,interest_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'分配股利' as fee_type
,dividend_out_amt AS amt
FROM amt_base
UNION ALL
SELECT
stat_date
,'支出' AS fee_class
,'其他(捐赠等)' as fee_type
,other_out_amt AS amt
FROM amt_base
)
SELECT
fee_class
,fee_type
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM-dd') = '${FORMAT(today(),"yyyy-MM-dd")}'
THEN amt ELSE 0 END) / 10000 AS today_amt -- 本日
,SUM(CASE WHEN to_char(stat_date,'yyyy-MM') = '${FORMAT(today(),"yyyy-MM")}'
THEN amt ELSE 0 END) / 10000 AS month_amt -- 本月累计
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(today(),"yyyy")}'
THEN amt ELSE 0 END) / 10000 AS year_amt -- 本年累计
,SUM(CASE WHEN to_char(stat_date,'yyyy') = '${FORMAT(YEARDELTA(today(),-1),"yyyy")}'
THEN amt ELSE 0 END) / 10000 AS last_year_amt -- 去年同期累计
FROM amt_base_class
GROUP BY fee_type,fee_class
ORDER BY
decode(fee_type
,'成品酒销售回款','a'
,'散酒销售回款','b'
,'红包款/转货款/保证金/共建','c'
,'银行融资','d'
,'政府补助','e'
,'其他零星收款','f'
,'原辅低耗材料','g'
,'外购散酒','h'
,'外购包材/外协加工','i'
,'制造费用/能源费用','j'
,'广告/市场活动/庄园采购/储运','k'
,'共建支出','l'
,'经销商退款','m'
,'薪酬及福利','n'
,'税金缴纳','o'
,'管理费用/研发费用','p'
,'土地支出','q'
,'土建支出','r'
,'设备及维修支出','m'
,'归还贷款','n'
,'利息支出','o'
,'分配股利','v'
,'其他(捐赠等)','w'
)
-- ======================================
-- 本年期初现金余额
-- ======================================
--本月期初
with md as (
select
bank_account,
max(report_date) as max_report_date
from dwi.dwi_fim_bank_account_balance
where report_date<date_trunc('year',current_date)
group by bank_account
),xj as (
select
a.corp_code,
a.bank_account,
sum(a.current_balance) as current_balance,
a.currency
from dwi.dwi_fim_bank_account_balance a
where exists (
select 1 from md
where a.bank_account=md.bank_account and a.report_date=md.max_report_date
)
and a.account_state='开户'
group by a.corp_code, a.currency ,a.bank_account
) , rto as (/*汇率表*/
select decode(currency_name,'加拿大元','加元',currency_name) as currency_name,
conversion_price_boc/100 as rate,
date_trunc('day',exchange_publish_time) as rto_date,
row_number() over (partition by currency_name,
date_trunc('day',exchange_publish_time)
order by exchange_publish_time desc) as ridx
from sdi_xdata.boc_exchange_rate
where date_trunc('day',exchange_publish_time)=date_trunc('year',current_date)-1
)
select
re.corp_code,
sum(current_balance*nvl(rto.rate,1))/10000 as yb_balance,
if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0) as is_limit
from xj re
inner join dwr.dim_corp c on re.corp_code=c.corp_code and c.corp_group='股份'
left join rto on re.currency=rto.currency_name and rto.ridx=1
left join dwr.dim_bank_account dba on decode(length(re.bank_account), 17,
substring(re.bank_account, 3),
re.bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
where current_balance!=0
and exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
)
)
group by re.corp_code,if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0)
-- ======================================
-- 本日期初余额
-- ======================================
with tpj as (
select
a.corp_code,
'收入' as trade_direction,
draftcode,
a.owner_bank_account,
sum(a.amt) as amt
from sdi_oth.fim_draft_balance a
group by a.corp_code,
draftcode,
owner_bank_account
union all
select
a.corp_code,
trade_direction,
a.draftcode,
a.owner_bank_account,
amt
from dwr.fact_fim_draft_flow a
where a.trade_time>=date'2024-08-01'
and a.trade_time<date'${FORMAT(today(),"yyyy-MM-dd")}'
and nvl(a.draft_state,'x') not in ('未签收','背书中','登记中','已作废','承兑中','出票中','贴现中','质押中','收款中','被拒付','拒绝签收')
) ,pj as (/*票据余额*/
select
a.corp_code,
sum(decode(trade_direction,'支出',-1*amt,amt)) as balance
from tpj a
inner join dwr.dim_corp c on a.corp_code =c.corp_code and c.corp_group='股份'
group by a.corp_code
having sum(decode(trade_direction,'支出',-1*amt,amt))>0
), md as (
select
bank_account,
max(report_date) as max_report_date
from dwi.dwi_fim_bank_account_balance
where report_date<date'${FORMAT(today(),"yyyy-MM-dd")}'
group by bank_account
),re as (/*汇总票据和银行余额*/
select
a.corp_code,
a.current_balance,
a.currency,
'现金' as amt_type,
if((dba.category_name in ('专用户','保证金户') and a.bank_account!='22195901040000147' ) or a.bank_account='信用证保证金',1,0) as is_limit--受限资金金额
from dwi.dwi_fim_bank_account_balance a
inner join dwr.dim_corp c on a.corp_code=c.corp_code and c.corp_group='股份'
left join dwr.dim_bank_account dba on decode(length(a.bank_account), 17,
substring(a.bank_account, 3),
a.bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
where exists (
select 1 from md
where a.bank_account=md.bank_account and a.report_date=md.max_report_date
)
and a.account_state='开户'
union all
select
corp_code,
sum(balance) as current_balance,
'人民币' as currency,
'票据' as amt_type,
0 as is_limit
from pj
group by corp_code),
rto as (/*汇率表*/
select decode(currency_name,'加拿大元','加元',currency_name) as currency_name,
conversion_price_boc/100 as rate,
date_trunc('day',exchange_publish_time) as rto_date,
row_number() over (partition by currency_name,
date_trunc('day',exchange_publish_time)
order by exchange_publish_time desc) as ridx
from sdi_xdata.boc_exchange_rate
where date_trunc('day',exchange_publish_time)=date'${FORMAT(today(),"yyyy-MM-dd")}'
)
select
corp_code,
current_balance*nvl(rto.rate,1)/10000 as yb_balance,
amt_type,
is_limit
from re
left join rto on re.currency=rto.currency_name and rto.ridx=1
where current_balance!=0
and exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
)
)
-- ======================================
-- 本日期末余额
-- ======================================
with tpj as (
select
a.corp_code,
'收入' as trade_direction,
draftcode,
a.owner_bank_account,
sum(a.amt) as amt
from sdi_oth.fim_draft_balance a
group by a.corp_code,
draftcode,
owner_bank_account
union all
select
a.corp_code,
trade_direction,
a.draftcode,
a.owner_bank_account,
amt
from dwr.fact_fim_draft_flow a
where a.trade_time>=date'2024-08-01'
and a.trade_time<current_date + interval '1 day'
and nvl(a.draft_state,'x') not in ('未签收','背书中','登记中','已作废','承兑中','出票中','贴现中','质押中','收款中','被拒付','拒绝签收')
) ,pj as (/*票据余额*/
select
a.corp_code,
sum(decode(trade_direction,'支出',-1*amt,amt)) as balance
from tpj a
inner join dwr.dim_corp c on a.corp_code =c.corp_code and c.corp_group='股份'
group by a.corp_code
having sum(decode(trade_direction,'支出',-1*amt,amt))>0
), md as (
select
bank_account,
max(report_date) as max_report_date
from dwi.dwi_fim_bank_account_balance
where report_date<current_date + interval '1 day'
group by bank_account
),xj as (
select
a.corp_code,
a.bank_account,
sum(a.current_balance) as amt,
a.currency
from dwi.dwi_fim_bank_account_balance a
where exists (
select 1 from md
where a.bank_account=md.bank_account and a.report_date=md.max_report_date
)
and a.account_state='开户'
group by a.corp_code, a.currency ,a.bank_account
union all
select corp_code,
owner_bank_account as bank_account,
sum(decode(trade_direction,'收入',amt,-1*amt)) as amt,
'人民币' as currency
from dm.dm_fim_fud_indicator
where amt_type='现金'
and stat_date=current_date
group by corp_code,owner_bank_account
) ,re as (/*汇总票据和银行余额*/
select
a.corp_code,
sum(a.amt) as current_balance,
a.currency,
'现金' as amt_type,
if((dba.category_name in ('专用户','保证金户') and a.bank_account!='22195901040000147' ) or a.bank_account='信用证保证金',1,0) as is_limit--受限资金金额
from xj a
inner join dwr.dim_corp c on a.corp_code=c.corp_code and c.corp_group='股份'
left join dwr.dim_bank_account dba on decode(length(a.bank_account), 17,
substring(a.bank_account, 3),
a.bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
group by a.corp_code,
a.currency,
if((dba.category_name in ('专用户','保证金户') and a.bank_account!='22195901040000147' ) or a.bank_account='信用证保证金',1,0)
union all
select
corp_code,
sum(balance) as current_balance,
'人民币' as currency,
'票据' as amt_type,
0 as is_limit
from pj
group by corp_code),
rto as (/*汇率表*/
select decode(currency_name,'加拿大元','加元',currency_name) as currency_name,
conversion_price_boc/100 as rate,
date_trunc('day',exchange_publish_time) as rto_date,
row_number() over (partition by currency_name,
date_trunc('day',exchange_publish_time)
order by exchange_publish_time desc) as ridx
from sdi_xdata.boc_exchange_rate
where date_trunc('day',exchange_publish_time)=current_date
)
select
corp_code,
current_balance*nvl(rto.rate,1)/10000 as yb_balance,
amt_type,
is_limit
from re
left join rto on re.currency=rto.currency_name and rto.ridx=1
where current_balance!=0
and exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
)
)
-- ======================================
-- 本月期初现金余额
-- ======================================
--本月期初
with md as (
select
bank_account,
max(report_date) as max_report_date
from dwi.dwi_fim_bank_account_balance
where report_date<date_trunc('month',current_date)
group by bank_account
),xj as (
select
a.corp_code,
a.bank_account,
sum(a.current_balance) as current_balance,
a.currency
from dwi.dwi_fim_bank_account_balance a
where exists (
select 1 from md
where a.bank_account=md.bank_account and a.report_date=md.max_report_date
)
and a.account_state='开户'
group by a.corp_code, a.currency ,a.bank_account
) , rto as (/*汇率表*/
select decode(currency_name,'加拿大元','加元',currency_name) as currency_name,
conversion_price_boc/100 as rate,
date_trunc('day',exchange_publish_time) as rto_date,
row_number() over (partition by currency_name,
date_trunc('day',exchange_publish_time)
order by exchange_publish_time desc) as ridx
from sdi_xdata.boc_exchange_rate
where date_trunc('day',exchange_publish_time)=date_trunc('month',current_date)-1
)
select
re.corp_code,
sum(current_balance*nvl(rto.rate,1))/10000 as yb_balance,
if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0) as is_limit
from xj re
inner join dwr.dim_corp c on re.corp_code=c.corp_code and c.corp_group='股份'
left join rto on re.currency=rto.currency_name and rto.ridx=1
left join dwr.dim_bank_account dba on decode(length(re.bank_account), 17,
substring(re.bank_account, 3),
re.bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
where current_balance!=0
and exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
)
)
group by re.corp_code,if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0)
-- ======================================
-- 去年期初现金余额
-- ======================================
--本月期初
with md as (
select
bank_account,
max(report_date) as max_report_date
from dwi.dwi_fim_bank_account_balance
where report_date<date_trunc('year',current_date)-interval '1 year'
group by bank_account
),xj as (
select
a.corp_code,
a.bank_account,
sum(a.current_balance) as current_balance,
a.currency
from dwi.dwi_fim_bank_account_balance a
where exists (
select 1 from md
where a.bank_account=md.bank_account and a.report_date=md.max_report_date
)
and a.account_state='开户'
group by a.corp_code, a.currency ,a.bank_account
) , rto as (/*汇率表*/
select decode(currency_name,'加拿大元','加元',currency_name) as currency_name,
conversion_price_boc/100 as rate,
date_trunc('day',exchange_publish_time) as rto_date,
row_number() over (partition by currency_name,
date_trunc('day',exchange_publish_time)
order by exchange_publish_time desc) as ridx
from sdi_xdata.boc_exchange_rate
where date_trunc('day',exchange_publish_time)=date_trunc('year',current_date)-interval '1 year'-1
)
select
re.corp_code,
sum(current_balance*nvl(rto.rate,1))/10000 as yb_balance,
if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0) as is_limit
from xj re
inner join dwr.dim_corp c on re.corp_code=c.corp_code and c.corp_group='股份'
left join rto on re.currency=rto.currency_name and rto.ridx=1
left join dwr.dim_bank_account dba on decode(length(re.bank_account), 17,
substring(re.bank_account, 3),
re.bank_account)=decode(length(dba.accountnumber), '17',
substring(dba.accountnumber, 3),
dba.accountnumber)
and dba.account_owner_class='langjiu'
where current_balance!=0
and exists (
select
1
from
dm.dm_bi_user_permisson
where
bi_user = '${fine_username}'
and per_model IN ('all','fim')
and (
is_all = 1
)
)
group by re.corp_code,if((dba.category_name in ('专用户','保证金户') and re.bank_account!='22195901040000147' ) or re.bank_account='信用证保证金',1,0)