合同业务主表.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144
  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. TRIM(TRAILING ',' FROM CONCAT(
  9. IF(crc.contract_status = 1 AND crc.contract_sub_status = 1, '待处理,', ''),
  10. IF(crc.contract_status = 1 AND crc.contract_sub_status = 2 AND crc.sign_status = 1, '待租客签字,', ''),
  11. IF(crc.contract_status = 1 AND crc.contract_sub_status = 2 AND crc.sign_status = 0, '带租客实名,', ''),
  12. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND LENGTH(trim(crc.`down_payment_info`)) > 1 AND JSON_EXTRACT(crc.`down_payment_info`, '$.status') = 0, '待付款,', ''),
  13. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND crc.is_sync_tenant = 1, '待租客确认,', ''),
  14. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND DATE(NOW()) < crc.begin_time, '即将搬入,', ''),
  15. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND LENGTH(trim(crc.`down_payment_info`)) > 1 AND (JSON_EXTRACT(crc.`down_payment_info`, '$.status') = 1 AND DATE(NOW()) >= crc.begin_time AND DATE(NOW()) < DATE_ADD(DATE(crc.end_time), INTERVAL 30 DAY) ), '租约中,', ''),
  16. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND crc.`begin_time` <= DATE(NOW()) AND DATE(NOW()) >= DATE_ADD(DATE(crc.end_time), INTERVAL 30 DAY) AND DATE(NOW())< DATE(crc.end_time), '即将到期,', ''),
  17. IF(crc.contract_status = 2 AND crc.transition_type != 1 AND DATE(NOW()) >= DATE(crc.end_time), '已到期,', ''),
  18. IF(crc.contract_status = 2 AND crc.transition_type = 1, '已续约,', ''),
  19. IF(crc.contract_status = 3 AND crc.terminate_type = 1, '正常退,', ''),
  20. IF(crc.contract_status = 3 AND crc.terminate_type = 2, '违约退,', ''),
  21. IF(crc.contract_status = 4 AND crc.invalid_type = 1, '已作废,', ''),
  22. IF(crc.contract_status = 4 AND crc.invalid_type = 2, '已拒绝,', '')
  23. )) '合同状态',
  24. crc.approval_status '审批状态',
  25. 0 'splitter',
  26. IF((_deposit.应付-_deposit.已付), (_deposit.应付-_deposit.已付), 0) '押金余额',
  27. IF((_total.应收), (_total.应收), 0) '应收总金额',
  28. IF((_total.应付), (_total.应付), 0) '应付总金额',
  29. IF((_this_month.应收), (_this_month.应收), 0) '本月应收',
  30. IF((_this_month.已收), (_this_month.已收), 0) '本月已收',
  31. IF((_this_month.应付), (_this_month.应付), 0) '本月应付',
  32. IF((_this_month.已付), (_this_month.已付), 0) '本月已付',
  33. IF((_until_this_month.应收), (_until_this_month.应收), 0) '截止至本月应收',
  34. IF((_until_this_month.已收), (_until_this_month.已收), 0) '截止至本月已收',
  35. IF((_until_this_month.应付), (_until_this_month.应付), 0) '截止至本月应付',
  36. IF((_until_this_month.已付), (_until_this_month.已付), 0) '截止至本月已付',
  37. IF((_until_this_month.应收-_until_this_month.已收), (_until_this_month.应收-_until_this_month.已收), 0) '截止至本月待收',
  38. IF((_until_this_month.应付-_until_this_month.已付), (_until_this_month.应付-_until_this_month.已付), 0) '截止至本月待付',
  39. IF((_over_due.应收-_over_due.已收), (_over_due.应收-_over_due.已收), 0) '截止至本日逾期待收',
  40. IF((_over_due.应付-_over_due.已付), (_over_due.应付-_over_due.已付), 0) '截止至本日逾期待付',
  41. IF((_until_last_month.已收), (_until_last_month.已收), 0) '截止至上月已收',
  42. IF((_until_last_month.已付), (_until_last_month.已付), 0) '截止至上月已付',
  43. IF(_this_month_flow.审核通过收入, _this_month_flow.审核通过收入, 0) '本月审核通过收入',
  44. IF(_this_month_flow.审核通过支出, _this_month_flow.审核通过支出, 0) '本月审核通过支出',
  45. IF(_this_month_flow.待审核收入, _this_month_flow.待审核收入, 0) '本月待审核收入',
  46. IF(_this_month_flow.待审核支出, _this_month_flow.待审核支出, 0) '本月待审核支出',
  47. IF(_until_this_month_flow.审核通过收入, _until_this_month_flow.审核通过收入, 0) '截止至本月审核通过收入',
  48. IF(_until_this_month_flow.审核通过支出, _until_this_month_flow.审核通过支出, 0) '截止至本月审核通过支出',
  49. IF(_until_this_month_flow.待审核收入, _until_this_month_flow.待审核收入, 0) '截止至本月待审核收入',
  50. IF(_until_this_month_flow.待审核支出, _until_this_month_flow.待审核支出, 0) '截止至本月待审核支出',
  51. IF(_until_this_month_flow.审核通过收入, _until_this_month_flow.审核通过收入, 0)-IF(_this_month_flow.审核通过收入, _this_month_flow.审核通过收入, 0) '截止至上月审核通过收入',
  52. IF(_until_this_month_flow.审核通过支出, _until_this_month_flow.审核通过支出, 0)-IF(_this_month_flow.审核通过支出, _this_month_flow.审核通过支出, 0) '截止至上月审核通过支出'
  53. from yuxin_contract.cont_renter_contract crc
  54. left join yuxin_house.hse_house_room hhr on hhr.is_delete=0 and hhr.id=crc.house_id
  55. left join yuxin_house.hse_house_base hhb on hhb.is_delete=0 and hhb.id=crc.house_id
  56. left join yuxin_setting.setting_department house_sd on house_sd.id=hhb.dept_id and house_sd.is_delete=0
  57. left join yuxin_house.hse_community hc on hc.id=hhb.community_id and hc.is_delete=0
  58. left join yuxin_setting.setting_employee_dept crc_ed on crc_ed.emp_id=crc.maintainer_id and crc_ed.is_delete=0
  59. left join yuxin_setting.setting_department crc_sd on crc_sd.id=crc_ed.dept_id and crc_sd.is_delete=0
  60. left join yuxin_contract.cont_renter_info cri on cri.is_delete=0 and cri.customer_type=1 and cri.contract_id=crc.id
  61. left join yuxin_setting.setting_employee_info sign_emp on sign_emp.id=crc.sign_emp_id and sign_emp.is_delete=0
  62. left join yuxin_setting.setting_employee_info mt_emp on mt_emp.id=crc.maintainer_id and mt_emp.is_delete=0
  63. left join (
  64. select bd.biz_id,
  65. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  66. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付'
  67. from yuxin_finance.fin_finance_bill_detail bd
  68. left join yuxin_setting.setting_dictionary sd on sd.id=bd.fee_subject_id
  69. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and sd.label='FEESUBJECT@DEPOSIT'
  70. group by bd.biz_id
  71. ) _deposit on _deposit.biz_id= crc.id
  72. left join (
  73. select bd.biz_id,
  74. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  75. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  76. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  77. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  78. from yuxin_finance.fin_finance_bill_detail bd
  79. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2
  80. group by bd.biz_id
  81. ) _total on _total.biz_id= crc.id
  82. left join (
  83. select bd.biz_id,
  84. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  85. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  86. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  87. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  88. from yuxin_finance.fin_finance_bill_detail bd
  89. 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())
  90. group by bd.biz_id
  91. ) _this_month on _this_month.biz_id= crc.id
  92. left join (
  93. select bd.biz_id,
  94. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  95. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  96. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  97. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  98. from yuxin_finance.fin_finance_bill_detail bd
  99. 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
  100. group by bd.biz_id
  101. ) _over_due on _over_due.biz_id= crc.id
  102. left join (
  103. select bd.biz_id,
  104. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  105. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  106. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  107. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  108. from yuxin_finance.fin_finance_bill_detail bd
  109. 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())
  110. group by bd.biz_id
  111. ) _until_this_month on _until_this_month.biz_id= crc.id
  112. left join (
  113. select bd.biz_id,
  114. SUM(IF(bd.fee_direction=1,0,1)*bd.original_money) '应付',
  115. SUM(IF(bd.fee_direction=1,0,1)*bd.occurred_money) '已付',
  116. SUM(IF(bd.fee_direction=1,1,0)*bd.original_money) '应收',
  117. SUM(IF(bd.fee_direction=1,1,0)*bd.occurred_money) '已收'
  118. from yuxin_finance.fin_finance_bill_detail bd
  119. where bd.is_valid=1 and bd.is_delete=0 and bd.biz_type=2 and bd.practical_time < CAST(DATE_FORMAT(NOW() ,'%Y-%m-01') as DATE)
  120. group by bd.biz_id
  121. ) _until_last_month on _until_last_month.biz_id= crc.id
  122. left join (
  123. select bf.biz_id,
  124. SUM(IF(bf.fee_direction=1,0,1)*IF(bf.audit_status=2,1,0)*ABS(bf.total_money)) '审核通过收入',
  125. SUM(IF(bf.fee_direction=1,1,0)*IF(bf.audit_status=2,1,0)*ABS(bf.total_money)) '审核通过支出',
  126. SUM(IF(bf.fee_direction=1,0,1)*IF(bf.audit_status=1,1,0)*ABS(bf.total_money)) '待审核收入',
  127. SUM(IF(bf.fee_direction=1,1,0)*IF(bf.audit_status=1,1,0)*ABS(bf.total_money)) '待审核支出'
  128. from yuxin_finance.fin_finance_bill_flow bf
  129. where bf.is_valid=1 and bf.is_delete=0 and bf.biz_type=2 and
  130. MONTH(bf.audit_time) = MONTH(CURRENT_DATE()) AND YEAR(bf.audit_time) = YEAR(CURRENT_DATE())
  131. group by bf.biz_id
  132. ) _this_month_flow on _this_month_flow.biz_id=crc.id
  133. left join (
  134. select bf.biz_id,
  135. SUM(IF(bf.fee_direction=1,0,1)*IF(bf.audit_status=2,1,0)*ABS(bf.total_money)) '审核通过收入',
  136. SUM(IF(bf.fee_direction=1,1,0)*IF(bf.audit_status=2,1,0)*ABS(bf.total_money)) '审核通过支出',
  137. SUM(IF(bf.fee_direction=1,0,1)*IF(bf.audit_status=1,1,0)*ABS(bf.total_money)) '待审核收入',
  138. SUM(IF(bf.fee_direction=1,1,0)*IF(bf.audit_status=1,1,0)*ABS(bf.total_money)) '待审核支出'
  139. from yuxin_finance.fin_finance_bill_flow bf
  140. where bf.is_valid=1 and bf.is_delete=0 and bf.biz_type=2 and
  141. MONTH(bf.audit_time) <= MONTH(CURRENT_DATE()) AND YEAR(bf.audit_time) <= YEAR(CURRENT_DATE())
  142. group by bf.biz_id
  143. ) _until_this_month_flow on _until_this_month_flow.biz_id=crc.id
  144. where crc.is_delete=0 and crc.contract_status<>4