退房业务报表.sql 3.7 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849
  1. select crc.tenant_id, crc.id '合同ID', hhb.dept_id '房源所属门店ID', house_sd.name '房源所属门店', maintainer_sd.id '所属门店ID', maintainer_sd.name '所属门店', hhr.address '房源地址', mt_emp.name '合同维护人',
  2. cri.name '租客姓名', crc.begin_time '合同开始日期', crc.end_time '合同结束日期',
  3. crc.quite_date '退租日期', crc.terminate_type '退租类型',
  4. case when JSON_EXTRACT(crc.`cancel_info`, '$.paymentAccountType')=1 then '银联'
  5. when JSON_EXTRACT(crc.`cancel_info`, '$.paymentAccountType')=2 then '支付宝'
  6. when JSON_EXTRACT(crc.`cancel_info`, '$.paymentAccountType')=3 then '微信' end '退款途径',
  7. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.paymentAccount'), '"', ''), 'null', '') '退款账号',
  8. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.bankName'), '"', ''), 'null', '') '银行行号',
  9. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.bankNumber'), '"', ''), 'null', '') '开户银行',
  10. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.reason'), '"', ''), 'null', '') '退租备注',
  11. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.rejectName'), '"', ''), 'null', '') '退租操作人',
  12. REPLACE(REPLACE(JSON_EXTRACT(crc.`cancel_info`, '$.rejectTime'), '"', ''), 'null', '') '退租时间',
  13. _total.direction '费用方向',
  14. _total.kind '费用科目',
  15. _total.original_money '金额',
  16. _total.应退款金额 '应退款金额',
  17. _detail.info '财务退款备注',
  18. IF(_flow_status.avg_status is null, '-', IF(_flow_status.avg_status=1, '待审核', IF(_flow_status.avg_status=2, '审核通过', '部分审核通过'))) '审核状态',
  19. IF(_flow_status.avg_status is null, '未处理', IF(_flow_status.avg_status=2, '已退款', IF(_flow_status.avg_status>1, '已部分退款', '未退款'))) '退款信息'
  20. from yuxin_contract.cont_renter_contract crc
  21. left join yuxin_house.hse_house_base hhb on hhb.is_delete=0 and hhb.id=crc.house_id
  22. left join yuxin_setting.setting_department house_sd on house_sd.id=hhb.dept_id and house_sd.is_delete=0
  23. left join yuxin_house.hse_house_room hhr on hhr.is_delete=0 and hhr.id=crc.house_id
  24. left join yuxin_setting.setting_employee_dept maintainer_ed on maintainer_ed.emp_id=crc.maintainer_id and maintainer_ed.is_delete=0
  25. left join yuxin_setting.setting_department maintainer_sd on maintainer_sd.id=maintainer_ed.dept_id and maintainer_sd.is_delete=0
  26. left join yuxin_setting.setting_employee_info mt_emp on mt_emp.id=crc.maintainer_id and mt_emp.is_delete=0
  27. left join yuxin_contract.cont_renter_info cri on cri.is_delete=0 and cri.customer_type=1 and cri.contract_id=crc.id
  28. left join (
  29. select bd.biz_id, sd.name 'kind', IF(bd.fee_direction=1,'应收','应付') 'direction', SUM(bd.original_money) 'original_money',
  30. SUM(IF(bd.fee_direction = 2, 1, -1) * bd.original_money) '应退款金额'
  31. from yuxin_finance.fin_finance_bill_detail bd
  32. left join yuxin_setting.setting_dictionary sd on sd.id=bd.fee_subject_id
  33. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2
  34. group by bd.biz_id,sd.name,bd.fee_direction
  35. ) _total on _total.biz_id= crc.id
  36. left join (
  37. select bd.biz_id, GROUP_CONCAT(CONCAT(sd.name, IF(bd.fee_direction=1,1,-1)*bd.original_money)) 'info'
  38. from yuxin_finance.fin_finance_bill_detail bd
  39. left join yuxin_setting.setting_dictionary sd on sd.id=bd.fee_subject_id
  40. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and bd.fee_direction=2
  41. group by bd.biz_id
  42. ) _detail on _detail.biz_id=crc.id
  43. left join (
  44. select bf.biz_id, avg(bf.audit_status) 'avg_status'
  45. from yuxin_finance.fin_finance_bill_flow bf
  46. where bf.is_delete=0 and bf.biz_type=2 and bf.bill_type=2
  47. group by bf.biz_id
  48. ) _flow_status on _flow_status.biz_id=crc.id
  49. where crc.contract_status=3 and crc.is_delete=0