leading-project/dw/dws/dws_law_tran_coll_d.sql
2024-11-27 11:07:58 +08:00

92 lines
4.1 KiB
SQL

select
e.organ_code, e.organ_name, e.comm_id, e.comm_name
, case when project_name like '%撤场%' then '撤场' else '在管' end is_in_manage
, case when a.status_id in (5,6) then '诉讼'
when a.status_id in (4,7) then '非诉'
else ifnull(c.case_type,b.case_type) end is_lawsuit
, sum(a.trans_amt) trans_amt
, count(distinct a.belong_resource) trans_household_num
, 0 payment_coll_amt
, 0 payment_coll_num
, b.apply_date ymd
, datediff(ifnull(str_to_date(c.wjsj,'%Y-%m-%d'),current_date()),str_to_date(b.apply_date,'%Y-%m-%d')) trans_duration
, a.collect_unit
, a.acct_age
from (
select a.*
, zl acct_age -- 给所属资源打上账龄
from dwd_law_owed_info_d a
left join (
/*取高层物业费或者车位物业费作为账龄的标记*/
select *
from (
select belong_resource , cost_name , count(*) zl
, row_number() over (partition by belong_resource order by if(cost_name = '高层物业服务费',1,if(cost_name = '车位物业服务费',2,9)) asc) rn
from dwd_law_owed_info_d
where status_id in (6,7,8,9,10,11)
group by belong_resource , cost_name
) a where rn = 1
) b
on a.belong_resource = b.belong_resource
where status_id in (6,7,8,9,10,11)
) a
left join (
select a.trans_payment, a.apply_date, b.return_date , case when a.trans_type = 0 then '诉讼' else '非诉' end case_type
from dwd_law_trans_record_d a
left join dwd_law_trans_return_record_d b
on a.trans_payment = b.owed_payment
where str_to_date(a.apply_date,'%Y-%m-%d') > ifnull(date_format(b.return_date,'%Y-%m-%d'),'2000-01-01')
) b
on a.id = b.trans_payment
left join (
select * from (
select
a.case_type
, a.wjsj
, b.owed_id
, a.collect_unit
, row_number() over (partition by owed_id order by if(status in ('草稿','作废'),1,0) asc) rn
from dwd_law_case_info_d a
left join dwd_law_case_detail_d b
on a.id = b.case_id
) a
where rn = 1
) c
on a.id = c.owed_id
inner join (select distinct organ_code, organ_name, comm_id, comm_name from dim_organ_mapping) e
on a.project_code = e.comm_id
group by 1,2,3,4,5,6,11,12,13,14
union all
select
a.district_code organ_code
, a.district_name organ_name
, a.project_code comm_id
, a.project_name comm_name
, case when a.project_name like '%撤场%' then '撤场' else '在管' end is_in_manage
, b.case_type is_lawsuit
, 0, 0
, sum(a.payment_coll_amt) payment_coll_amt
, sum(case when a.rn =1 then 1 else 0 end) payment_coll_num
, a.apply_date ymd
, null
, b.collect_unit
, a.acct_age
from (
select a.*, b.zl acct_age, row_number() over (partition by district_code, a.belong_resource order by a.apply_date asc) rn
from dwd_law_payment_collection_d a
left join (
/*取高层物业费或者车位物业费作为账龄的标记*/
select *
from (
select belong_resource , cost_name , count(*) zl
, row_number() over (partition by belong_resource order by if(cost_name = '高层物业服务费',1,if(cost_name = '车位物业服务费',2,9)) asc) rn
from dwd_law_owed_info_d
where status_id in (6,7,8,9,10,11)
group by belong_resource , cost_name
) a where rn = 1
) b
on a.belong_resource = b.belong_resource
) a
left join dwd_law_case_info_d b
on a.case_name = b.id
group by 1,2,3,4,5,6,11,13,14