yanghb
2025-05-07 bf8f34752cc7584193d490cd6c1fe5850d31a269
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="com.ruoyi.bussiness.mapper.PlacementBatchHouseholdMapper">
 
    <select id="reportPlacementHouseholdSum"
            resultType="com.ruoyi.bussiness.object.response.report.ReportSumResponse">
        SELECT sum(t1.compensation_sum) as compensation_sum,
               sum(t1.down_payment_amount) as down_payment_amount,
               sum(t1.subsidy_amount) as subsidy_amount,
               sum(t1.quarter_pay_amount)*20 as quarter_pay_amount
        FROM t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        <if test="street != null and street != ''">
            and t1.street = #{street}
        </if>
    </select>
 
 
    <select id="reportPage" resultType="java.util.Map">
        SELECT
        t1.street,
        sum(t1.current_count) as currentCount,
        sum(t1.down_payment_amount) as downPaymentAmount,
        sum(t1.subsidy_amount) as subsidyAmount,
        sum(t1.compensation_sum) as compensationSum,
        <foreach collection="request.quarters" item="quarter" separator=",">
            SUM(CASE
            WHEN FIND_IN_SET(#{quarter}, cycle) > 0
            THEN t1.quarter_pay_amount
            ELSE 0
            END) AS `${quarter}`
        </foreach>
        FROM
        t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        <if test="request.street != null and request.street != ''">
            and t1.street = #{request.street}
        </if>
        GROUP BY
        street
    </select>
 
    <select id="reportExportsList" resultType="java.util.Map">
        SELECT
        t1.street,
        sum(t1.current_count) as currentCount,
        sum(t1.down_payment_amount) as downPaymentAmount,
        sum(t1.subsidy_amount) as subsidyAmount,
        sum(t1.compensation_sum) as compensationSum,
        <foreach collection="request.quarters" item="quarter" index="index" separator=",">
            SUM(CASE
            WHEN FIND_IN_SET(#{quarter}, cycle) > 0
            THEN t1.quarter_pay_amount
            ELSE 0
            END) AS value${index + 1}
        </foreach>
        FROM
        t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        <if test="request.street != null and request.street != ''">
            and t1.street = #{request.street}
        </if>
        GROUP BY
        street
    </select>
 
    <select id="detailPage" resultType="com.ruoyi.bussiness.object.response.report.DetailResponse">
        select t1.*,t2.batch_number
        from t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        <if test="request.street != null and request.street != ''">
            and t1.street like concat('%', #{request.street}, '%')
        </if>
        <if test="request.community != null and request.community != ''">
            and t1.community like concat('%', #{request.community}, '%')
        </if>
        <if test="request.batchNumber != null and request.batchNumber != ''">
            and t2.batch_number like concat('%', #{request.batchNumber}, '%')
        </if>
        <if test="request.householdHead != null and request.householdHead != ''">
            and t1.household_head like concat('%', #{request.householdHead}, '%')
        </if>
    </select>
 
    <select id="sumCurrentMonth" resultType="java.math.BigDecimal">
        select IFNULL(sum(t1.subsidy_amount+t1.down_payment_amount),0)
        from t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        AND DATE_FORMAT(t1.compensation_pay_time, '%Y-%m') = #{month};
    </select>
    
    <select id="countCurrentPerson" resultType="java.math.BigDecimal">
        SELECT IFNULL(SUM(t1.current_count),0)
        FROM t_placement_batch_household t1
                 LEFT JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
        WHERE t2.status = 1
          AND t1.sign_time >= DATE_SUB(NOW(), INTERVAL 2 MONTH);
    </select>
    
    <select id="getStreetResponse" resultType="com.ruoyi.bussiness.object.response.screen.StreetResponse">
        WITH RankedBatches AS (
            SELECT
                t2.id AS batch_id,
                t1.street,
                SUM(t1.current_count) AS household_count,
                ROW_NUMBER() OVER (PARTITION BY t1.street ORDER BY t2.approve_time DESC) AS batch_rank
            FROM t_placement_batch_household t1
                     LEFT JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
            GROUP BY t2.id, t1.street, t2.approve_time
        ),
             StreetTotal AS (
                 SELECT
                     t1.street,
                     SUM(t1.current_count) AS householdNum
                 FROM t_placement_batch_household t1
                          LEFT JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
                 WHERE t2.status = 1
                 GROUP BY t1.street
             )
        SELECT
            st.street,
            st.householdNum,  -- ✅ 保持你的字段名不变(总人数)
 
            COALESCE(MAX(CASE WHEN rb.batch_rank = 1 THEN rb.household_count END), 0) AS latest_batch_household_count,
 
            COALESCE(MAX(CASE WHEN rb.batch_rank = 2 THEN rb.household_count END), 0) AS second_latest_batch_household_count
 
        FROM StreetTotal st
                 LEFT JOIN RankedBatches rb ON st.street = rb.street
        GROUP BY st.street
        ORDER BY householdNum DESC
    </select>
    
    <select id="getImportErrorResponse" resultType="com.ruoyi.bussiness.object.response.screen.ImportErrorResponse">
        SELECT DATE_FORMAT(create_time, '%Y-%m') AS month,
        SUM(compensation_num) AS moneyErrorCount,
        SUM(area_num) AS areaErrorCount
        from t_placement_error
        GROUP BY month
        ORDER BY month ASC
    </select>
 
    <select id="getMapResponse" resultType="com.ruoyi.bussiness.object.response.screen.MapResponse">
        SELECT
            t1.street AS street,  -- 街道名称
            COUNT(DISTINCT t1.id) AS household_count,  -- 统计总户数(去重 ID 计数)
            SUM(t1.current_count) AS person_count  -- 统计安置总人数
        from t_placement_batch_household t1
                 left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        WHERE t2.status = 1  -- 仅统计 status = 1 的数据
        GROUP BY t1.street
        ORDER BY household_count DESC;  -- 按总户数降序排序
    </select>
    
    <select id="getQuarterProcessResponse" resultType="com.ruoyi.bussiness.object.response.screen.QuarterProcessResponse">
        SELECT
            t2.batch_number,
            t1.household_head,
            t1.current_count,
            t1.compensation_pay_time
        from t_placement_batch_household t1
        left join t_placement_batch t2
        on t1.placement_batch_id = t2.id
        WHERE t2.status = 1  -- 仅统计 status = 1 的数据
        <if test="request.houseHead != null and request.houseHead != ''">
            and t1.household_head like concat('%', #{request.houseHead}, '%')
        </if>
        and t1.compensation_pay_time is not null
        ORDER BY t2.id DESC
    </select>
 
 
    <select id="getPlacementTypeResponse" resultType="com.ruoyi.bussiness.object.response.screen.PlacementTypeResponse">
        WITH type_summary AS (
            -- 计算各类型的面积和数量
            SELECT
                '新建商品住房' AS type,
                SUM(t1.new_housing_area) AS area,
                SUM(t1.new_housing_num) AS total
            FROM t_placement_batch_household t1
                     JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
 
            UNION ALL
 
            SELECT
                '商业用房',
                SUM(t1.build_housing_area),
                SUM(t1.build_housing_num)
            FROM t_placement_batch_household t1
                     JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
 
            UNION ALL
 
            SELECT
                '二手房',
                SUM(t1.old_housing_area),
                SUM(t1.old_housing_num)
            FROM t_placement_batch_household t1
                     JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
 
            UNION ALL
 
            SELECT
                '停车位',
                0,
                SUM(t1.new_stop_num)
            FROM t_placement_batch_household t1
                     JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
        )
        SELECT
            type,
            area,
            total,
            CONCAT(ROUND(total / NULLIF((SELECT SUM(total) FROM type_summary), 0) * 100, 2), '%') AS rate
        FROM type_summary
        ORDER BY FIELD(type, '新建商品住房', '商业用房', '二手房', '停车位')
    </select>
 
    <select id="getMonthCompensationResponse" resultType="com.ruoyi.bussiness.object.response.screen.MonthCompensationResponse">
        WITH month_total AS (
            -- 计算 2025-03 当月的总金额
            SELECT
                SUM(CASE
                        WHEN DATE_FORMAT(t1.compensation_pay_time, '%Y-%m') = #{month}
                            THEN t1.subsidy_amount
                        ELSE 0
                    END) AS month_compensation,
                SUM(CASE
                        WHEN DATE_FORMAT(t1.compensation_pay_time, '%Y-%m') = #{month}
                            THEN t1.down_payment_amount
                        ELSE 0
                    END) AS month_down_payment,
                IFNULL(SUM(CASE
                               WHEN FIND_IN_SET(#{month}, cycle) > 0
                                   THEN t1.quarter_pay_amount
                               ELSE 0
                    END), 0) AS month_quarter_payment
            FROM t_placement_batch_household t1
                     JOIN t_placement_batch t2 ON t1.placement_batch_id = t2.id
            WHERE t2.status = 1
        )
        SELECT '过渡补贴' AS type,
               COALESCE(month_total.month_compensation, 0) AS amount,
               CONCAT(ROUND(month_total.month_compensation /
                            NULLIF((month_total.month_compensation + month_total.month_down_payment + month_total.month_quarter_payment), 0) * 100, 2), '%') AS amountRate
        FROM month_total
        UNION ALL
        SELECT '25%首付款',
               COALESCE(month_total.month_down_payment, 0),
               CONCAT(ROUND(month_total.month_down_payment /
                            NULLIF((month_total.month_compensation + month_total.month_down_payment + month_total.month_quarter_payment), 0) * 100, 2), '%')
        FROM month_total
        UNION ALL
        SELECT '每季度需支付款项',
               COALESCE(month_total.month_quarter_payment, 0),
               CONCAT(ROUND(month_total.month_quarter_payment /
                            NULLIF((month_total.month_compensation + month_total.month_down_payment + month_total.month_quarter_payment), 0) * 100, 2), '%')
        FROM month_total
    </select>
    
    
    <select id="getQuarterPayResponse">
        SELECT
        <foreach collection="quarters" item="quarter" separator=",">
            SUM(CASE
            WHEN FIND_IN_SET(#{quarter}, cycle) > 0
            THEN t1.quarter_pay_amount
            ELSE 0
            END) AS `${quarter}`
        </foreach>
        FROM
        t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
    </select>
 
    <select id="getPayMoneyByQuarter" resultType="java.math.BigDecimal">
        SELECT
            ifnull(SUM(CASE
            WHEN FIND_IN_SET(#{quarter}, cycle) > 0
            THEN t1.quarter_pay_amount
            ELSE 0
            END),0) AS money
        FROM
        t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
    </select>
 
    <select id="getPlacementByIdCards" resultType="com.ruoyi.bussiness.domain.PlacementBatchHousehold">
       select t1.*
       from t_placement_batch_household t1
       left join t_placement_batch t2 on t1.placement_batch_id = t2.id
       where t2.status = 1
       and t1.id_card in
       <foreach collection="idCards" item="card" open="(" separator="," close=")">
           #{card}
       </foreach>
    </select>
    
    <select id="getHouseHistory" resultType="com.ruoyi.bussiness.domain.PlacementBatchHousehold">
        select t1.*
        from t_placement_batch_household t1
        left join t_placement_batch t2 on t1.placement_batch_id = t2.id
        where t2.status = 1
        and FIND_IN_SET(#{request.familyName},REPLACE(t1.wait_family_names,"、",","))
    </select>
    
</mapper>