合同业务主表.sql 6.7 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108
  1. select
  2. crc.tenant_id,
  3. hhb.dept_id '房源所属门店ID', house_sd.name '房源所属门店名称', hhr.address '房源地址', hhr.house_area '房源面积',
  4. crc_sd.id '合同所属门店/部门ID', crc_sd.name '合同所属门店/部门',
  5. crc.id '合同ID', crc.contract_no '合同编号', crc.maintainer_id '合同维护人ID', mt_emp.name '合同维护人',
  6. cri.name '租客姓名', crc.begin_time '合同开始日期', crc.end_time '合同结束日期', DATEDIFF(crc.end_time, crc.begin_time)+1 '签约天数',
  7. crc.`type` '合同类型', crc.sign_type '成交方式',
  8. (CASE -- 11-待处理
  9. WHEN crc.contract_status = 1 AND crc.contract_sub_status = 1 THEN 11
  10. -- 12-待租客签字
  11. WHEN crc.contract_status = 1 AND crc.contract_sub_status = 2
  12. and crc.sign_status = 1 THEN 12
  13. -- 18-带租客实名
  14. WHEN crc.contract_status = 1 AND crc.contract_sub_status=2
  15. and crc.sign_status = 0 THEN 18
  16. -- 21-待付款
  17. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND
  18. LENGTH(trim(crc.`down_payment_info`)) > 1 AND
  19. JSON_EXTRACT(crc.`down_payment_info`, '$.status') = 0 THEN 21
  20. -- 22-待租客确认
  21. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND crc.is_sync_tenant = 1 THEN 22
  22. -- 23-即将搬入
  23. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND DATE(NOW()) < crc.begin_time THEN 23
  24. -- 24-租约中
  25. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND
  26. LENGTH(trim(crc.`down_payment_info`)) > 1 AND
  27. (JSON_EXTRACT(crc.`down_payment_info`, '$.status') = 1 AND DATE(NOW()) >= crc.begin_time AND
  28. DATE(NOW()) < DATE_ADD(DATE(crc.end_time), INTERVAL 30 DAY) ) THEN 24
  29. -- 25-即将到期
  30. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND crc.`begin_time` <= DATE(NOW()) AND
  31. DATE(NOW()) >= DATE_ADD(DATE(crc.end_time), INTERVAL 30 DAY)
  32. AND DATE(NOW())< DATE(crc.end_time)THEN 25
  33. -- 26-已到期
  34. WHEN crc.contract_status = 2 AND crc.transition_type != 1 AND DATE(NOW()) >= DATE(crc.end_time) THEN 26
  35. -- 27-已续约
  36. WHEN crc.contract_status = 2 AND crc.transition_type = 1 THEN 27
  37. -- 31-正常退
  38. WHEN crc.contract_status = 3 AND crc.terminate_type = 1 THEN 31
  39. -- 32-违约退
  40. WHEN crc.contract_status = 3 AND crc.terminate_type = 2 THEN 32
  41. -- 41-已作废
  42. WHEN crc.contract_status = 4 AND crc.invalid_type = 1 THEN 41
  43. -- 42-已拒绝
  44. WHEN crc.contract_status = 4 AND crc.invalid_type = 2 THEN 42
  45. END) '合同状态',
  46. crc.approval_status '审批状态',
  47. 0 'splitter',
  48. IF((_deposit.应付-_deposit.已付), (_deposit.应付-_deposit.已付), 0) '押金余额',
  49. IF((_total.应收), (_total.应收), 0) '应收总金额',
  50. IF((_total.应付), (_total.应付), 0) '应付总金额',
  51. IF((_this_month.应收), (_this_month.应收), 0) '截止至本月应收',
  52. IF((_this_month.已收), (_this_month.已收), 0) '截止至本月已收',
  53. IF((_this_month.应付), (_this_month.应付), 0) '截止至本月应付',
  54. IF((_this_month.已付), (_this_month.已付), 0) '截止至本月已付',
  55. IF((_this_month.应收-_this_month.已收), (_this_month.应收-_this_month.已收), 0) '截止至本月待收',
  56. IF((_this_month.应付-_this_month.已付), (_this_month.应付-_this_month.已付), 0) '截止至本月待付',
  57. IF((_over_due.应收-_over_due.已收), (_over_due.应收-_over_due.已收), 0) '截止至本日逾期待收'
  58. from yuxin_contract.cont_renter_contract crc
  59. left join yuxin_house.hse_house_room hhr on hhr.is_delete=0 and hhr.id=crc.house_id
  60. left join yuxin_house.hse_house_base hhb on hhb.is_delete=0 and hhb.id=crc.house_id
  61. left join yuxin_setting.setting_department house_sd on house_sd.id=hhb.dept_id and house_sd.is_delete=0
  62. left join yuxin_house.hse_community hc on hc.id=hhb.community_id and hc.is_delete=0
  63. left join yuxin_setting.setting_employee_dept crc_ed on crc_ed.emp_id=crc.maintainer_id and crc_ed.is_delete=0
  64. left join yuxin_setting.setting_department crc_sd on crc_sd.id=crc_ed.dept_id and crc_sd.is_delete=0
  65. left join yuxin_contract.cont_renter_info cri on cri.is_delete=0 and cri.customer_type=1 and cri.contract_id=crc.id
  66. left join yuxin_setting.setting_employee_info sign_emp on sign_emp.id=crc.sign_emp_id and sign_emp.is_delete=0
  67. left join yuxin_setting.setting_employee_info mt_emp on mt_emp.id=crc.maintainer_id and mt_emp.is_delete=0
  68. left join (
  69. select bd.biz_id,
  70. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  71. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付'
  72. from yuxin_finance.fin_finance_bill_detail bd
  73. left join yuxin_setting.setting_dictionary sd on sd.id=bd.fee_subject_id
  74. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and sd.label='FEESUBJECT@DEPOSIT'
  75. group by bd.biz_id
  76. ) _deposit on _deposit.biz_id= crc.id
  77. left join (
  78. select bd.biz_id,
  79. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  80. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  81. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  82. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  83. from yuxin_finance.fin_finance_bill_detail bd
  84. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2
  85. group by bd.biz_id
  86. ) _total on _total.biz_id= crc.id
  87. left join (
  88. select bd.biz_id,
  89. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  90. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  91. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  92. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  93. from yuxin_finance.fin_finance_bill_detail bd
  94. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and MONTH(bd.predict_time) = MONTH(CURRENT_DATE()) AND YEAR(bd.predict_time) = YEAR(CURRENT_DATE())
  95. group by bd.biz_id
  96. ) _this_month on _this_month.biz_id= crc.id
  97. left join (
  98. select bd.biz_id,
  99. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  100. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  101. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  102. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  103. from yuxin_finance.fin_finance_bill_detail bd
  104. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and bd.predict_time < CURRENT_DATE() and bd.not_occurred_money>0
  105. group by bd.biz_id
  106. ) _over_due on _over_due.biz_id= crc.id
  107. where crc.is_delete=0
  108. and crc.id='1593183025861980161'