李林
2023-10-07 658d4927d468c47208fd012d9128b09249c07eff
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
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
<?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.chinaztt.mes.quality.mapper.ReportSampleMapper">
 
    <resultMap id="reportSampleMap" type="com.chinaztt.mes.quality.dto.ReportSampleDTO">
        <id property="id" column="id"/>
        <result property="reportId" column="report_id"/>
        <result property="sampleNo" column="sample_no"/>
        <result property="systemNo" column="system_no"/>
        <result property="remark" column="remark"/>
        <result property="testStandardNo" column="test_standard_no"/>
        <result property="outBatchNo" column="out_batch_no"/>
        <result property="testStandardId" column="test_standard_id"/>
        <result property="isMoTestStandard" column="is_mo_test_standard"/>
        <result property="reportType" column="report_type"/>
        <result property="partId" column="part_id"/>
        <result property="partNo" column="part_no"/>
        <result property="partName" column="part_name"/>
        <result property="stockQuantity" column="stock_quantity"/>
    </resultMap>
 
    <select id="getReportSampleList" resultMap="reportSampleMap">
        select
            temp.*
        from (SELECT
                  qrs.*,
                  CASE
                      WHEN ppo.out_batch_no IS NULL
                          THEN qap.lot_batch_no
                      ELSE ppo.out_batch_no END out_batch_no,
                  CASE
                      WHEN bp."id" IS NULL
                          THEN qap.part_no
                      ELSE bp.part_no END       part_no,
                  bp.ID                         part_id,
                  bp.part_name,
                  ws.stock_quantity
              FROM
                  quality_report_sample qrs
                      LEFT JOIN quality_apply_part qap ON qap.report_id = qrs.report_id
                      AND qap.system_no = qrs.system_no
                      LEFT JOIN production_product_output ppo ON ppo.system_no = qap.system_no
                      LEFT JOIN basic_part bp ON bp.ID = qap.part_id
                      LEFT JOIN warehouse_stock ws ON ws.part_batch_no = ppo.out_batch_no
              ORDER BY
                  qrs.sample_no DESC
             ) temp
        <if test="ew.emptyOfWhere == false">
            ${ew.customSqlSegment}
        </if>
    </select>
 
    <select id="getReportSampleForSelf" resultMap="reportSampleMap">
        select qrs.*
        from quality_report_sample qrs
        where qrs.system_no=#{sample.systemNo} and qrs.test_standard_id=#{sample.testStandardId}
        and exists(select 1 from quality_report qr where qr.report_type='04self' and qr."id"=qrs.report_id)
        order by qrs."id" limit 1
    </select>
 
    <select id="selectIsMasterRoutingOperationBySystemNo" resultType="java.lang.Boolean">
        select COALESCE(pmoro.is_master,FALSE)
        from production_product_output ppo
        left join production_product_main ppm on ppm."id"=ppo.product_main_id
        left join production_operation_task pot on pot."id"=ppm.operation_task_id
        left join plan_manufacturing_order_routing_operation pmoro on pot.mo_routing_operation_id = pmoro."id"
        where    ppo.system_no=#{systemNo}
        limit 1
    </select>
 
    <select id="selectSampleExpressionById" resultType="java.lang.String">
        select coalesce(pmts.judge_formula,qts.judge_formula)
        from quality_report_sample qrs
        left join quality_test_standard qts on qts."id"=qrs.test_standard_id and qrs.is_mo_test_standard=false
        left join plan_mo_test_standard pmts on pmts."id"=qrs.test_standard_id and qrs.is_mo_test_standard=true
        where qrs."id"=#{id}
    </select>
 
    <select id="getTestResult" resultType="com.chinaztt.mes.quality.dto.MoTestStandardParamDTO">
        SELECT DISTINCT pmtsp.parameter_item item_name, pmtsp.index
        FROM plan_mo_test_standard pmts
        LEFT JOIN plan_mo_test_standard_param pmtsp ON pmtsp.mo_test_standard_id = pmts."id"
        WHERE pmts.standard_no=#{standardNo} AND pmts.mo_id =#{moId} order by pmtsp.index asc
    </select>
 
    <select id="getTest" resultType="java.lang.String">
        SELECT array_to_string(array_agg(test_items),',') as item_name FROM(
        SELECT
        '"id" int8,"systemNo" VARCHAR,"lotBatchNo" VARCHAR,"partNo" VARCHAR,"partDesc" VARCHAR,"updateTime" TIMESTAMP,"isQualified" bool' AS test_items UNION ALL
        SELECT DISTINCT
        '"' || pmtsp.parameter_item || '" VARCHAR'
        FROM plan_mo_test_standard pmts
        LEFT JOIN plan_mo_test_standard_param pmtsp ON pmtsp.mo_test_standard_id = pmts."id"
        WHERE pmts.standard_no=#{standardNo} AND pmts.mo_id =#{moId}
        )E
    </select>
 
    <select id="getTestValue" resultType="com.alibaba.fastjson.JSONObject">
        SELECT
        *
        FROM
        crosstab ( 'SELECT
        qap."id",
        qap.system_no,
        qap.lot_batch_no,
        qap.part_no,
        qap.part_desc,
        qr.update_time,
        qap.is_qualified,
        qrsi.item_name,
        qrsi.item_value
        FROM
        quality_report qr
        LEFT JOIN quality_report_sample qrs  ON qr."id" = qrs.report_id
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrsi.report_sample_id = qrs."id"
        WHERE qrs.test_standard_no =''' ||#{queryDTO.testStandardNo}||'''  <if test="queryDTO.startTime!=null and queryDTO.startTime!='' "> and qr.update_time >= ''' ||#{queryDTO.startTime} </if><if test="queryDTO.endTime!=null and queryDTO.endTime!='' ">  ||''' and ''' ||#{queryDTO.endTime}||''' >= qr.update_time </if> <if test="queryDTO.lotBatchNo!=null and queryDTO.lotBatchNo!='' "> and qap.lot_batch_no LIKE ''' ||#{queryDTO.lotBatchNo}||'''</if> <if test="queryDTO.isQualified!=null "> and qap.is_qualified is ${queryDTO.isQualified}</if> order by 1','
        SELECT DISTINCT pmtsp.parameter_item item_name
        FROM plan_mo_test_standard pmts
        LEFT JOIN plan_mo_test_standard_param pmtsp ON pmtsp.mo_test_standard_id = pmts."id"
        WHERE pmts.standard_no=''' ||#{queryDTO.testStandardNo}||''' AND pmts.mo_id =${queryDTO.moId}' )  AS ( ${itemName} )
    </select>
 
    <select id="getBySystemNoAndReportType" resultMap="reportSampleMap">
        select qrs.* from quality_report_sample qrs
        left join quality_report qr on qrs.report_id = qr.id
        where
        qrs.system_no = #{systemNo}
    </select>
 
    <select id="getSampleById" resultMap="reportSampleMap">
        select qrs.*,qr.report_type from quality_report_sample qrs
        left join quality_report qr on qrs.report_id = qr.id
        where
        qr.id = #{reportId} order by qrs.id desc limit 1
    </select>
 
    <select id="getMoTestStandardId" resultType="java.lang.Long">
        SELECT pmts."id" FROM
        (SELECT * FROM production_product_output WHERE system_no = #{systemNo}) ppo
        LEFT JOIN
        production_product_main ppm ON ppo.product_main_id = ppm."id"
        LEFT JOIN
        production_operation_task pot ON ppm.operation_task_id = pot."id"
        LEFT JOIN
        production_operation_task_supply pots ON pot."id" = pots.operation_task_id
        LEFT JOIN
        plan_manufacturing_order_routing_operation pmoro ON pot.mo_routing_operation_id = pmoro."id"
        LEFT JOIN
        plan_mo_test_standard pmts ON pots.mo_id = pmts.mo_id AND pmts.mo_routing_operation_id = pmoro."id"
        INNER JOIN
        (SELECT * FROM quality_report WHERE "id" = #{reportId}) qr ON qr.report_type = pmts.inspection_type --检测汇报类型与制造订单检测标准类型一致
        LIMIT 1
    </select>
 
    <select id="getMoTestStandardNoById" resultType="java.lang.String">
        SELECT standard_no FROM plan_mo_test_standard WHERE "id" = #{id}
    </select>
 
    <select id="getTestStandardNoBySnOrPartId" resultType="java.lang.String">
        SELECT DISTINCT
            qrs.test_standard_no
        FROM
            quality_report_sample qrs
        LEFT JOIN quality_report qr ON qrs.report_id = qr.id
        LEFT JOIN quality_apply_part qap ON qr."id" = qap.report_id
        WHERE
            qr.report_type = #{testType}
            <if test="partBatchNo != null and partBatchNo != ''">
                AND qap.lot_batch_no = #{partBatchNo}
            </if>
            <if test="partId != null">
                AND qap.part_id = #{partId}
            </if>
    </select>
 
    <select id="getItemNameList" resultType="java.lang.String">
        SELECT DISTINCT
            qrsi.item_name,
            qrsi.sort
        FROM
            quality_report_sample qrs
            LEFT JOIN quality_report qr ON qrs.report_id = qr."id"
            LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
            LEFT JOIN quality_report_sample_item qrsi ON qrs."id" = qrsi.report_sample_id
        WHERE
            qrs.test_standard_no = #{testStandardNo}
              AND qr.report_type = #{testType}
            <if test="partId != null">
                  AND qap.part_id = #{partId}
              </if>
            <if test="partBatchNo != null and partBatchNo != ''">
                  AND qap.lot_batch_no = #{partBatchNo}
              </if>
        ORDER BY
            qrsi.sort ASC
    </select>
 
    <select id="getItemNameString" resultType="java.lang.String">
        SELECT array_to_string(array_agg(test_items),',') as item_name FROM(
        SELECT
        '"id" int8,"isQualified" bool,"partBatchNo" VARCHAR,"checkLength" numeric,
        "scrapArrived" numeric,"partNo" VARCHAR,"partDesc" VARCHAR,"replacePartNo" VARCHAR,
        "replacePartName" VARCHAR,"examiner" VARCHAR,"measuringInstrument" VARCHAR,"checkTime" TIMESTAMP,
        "reportPerson" VARCHAR,"reportType" VARCHAR,"workstationName" VARCHAR' AS test_items UNION ALL
        SELECT DISTINCT
        '"' || qrsi.item_name || '" VARCHAR'
        FROM
        quality_report_sample qrs
        LEFT JOIN quality_report qr ON qrs.report_id = qr."id"
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrs."id" = qrsi.report_sample_id
        WHERE
        qrs.test_standard_no = #{testStandardNo}
        AND qr.report_type = #{testType}
        <if test="partId != null">
            AND qap.part_id = #{partId}
        </if>
        <if test="partBatchNo != null and partBatchNo != ''">
            AND qap.lot_batch_no = #{partBatchNo}
        </if>
        )E
    </select>
 
    <select id="getTestValueV2" resultType="com.alibaba.fastjson.JSONObject">
        SELECT
        *
        FROM
        crosstab ( 'SELECT
        qap."id",
        qap.is_qualified,
        qap.lot_batch_no,
        qap.check_length,
        qap.scrap_arrived,
        qap.part_no,
        qap.part_desc,
        qap.replace_part_no,
        qap.replace_part_name,
        qap.examiner,
        qap.measuring_instrument,
        qr.check_time,
        qr.report_person,
        qr.report_type,
        bw."name" workstation_name,
        qrsi.item_name,
        qrsi.item_value || ''@'' || COALESCE(qrsi.is_qualified, TRUE)
        FROM
        quality_report qr
        LEFT JOIN quality_report_sample qrs ON qr."id" = qrs.report_id
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrsi.report_sample_id = qrs."id"
        LEFT JOIN production_product_output ppo ON qap.system_no = ppo.system_no
        LEFT JOIN production_product_main ppm ON ppo.product_main_id = ppm."id"
        LEFT JOIN production_operation_task pot ON ppm.operation_task_id = pot."id"
        LEFT JOIN basic_workstation bw ON ppm.workstation_id = bw."id"
        WHERE qrs.test_standard_no =''' ||#{queryDTO.testStandardNo}|| ''' AND qr.report_type =''' ||#{queryDTO.testType}||'''
        <if test="queryDTO.startTime!=null and queryDTO.startTime!='' "> and qr.check_time >= ''' ||#{queryDTO.startTime} </if>
        <if test="queryDTO.endTime!=null and queryDTO.endTime!='' ">  ||''' and ''' ||#{queryDTO.endTime}||''' >= qr.check_time </if>
        <if test="queryDTO.partBatchNo!=null and queryDTO.partBatchNo!='' "> and qap.lot_batch_no LIKE ''' ||#{queryDTO.partBatchNo}||'''</if>
        <if test="queryDTO.partId != null"> and qap.part_id = ${queryDTO.partId} </if>
        <if test="queryDTO.workstationIds != null and queryDTO.workstationIds != ''">
            and bw."id" in (  ${queryDTO.workstationIds}  )
        </if>
        <if test="queryDTO.isQualified!=null "> and qap.is_qualified is ${queryDTO.isQualified}</if> order by 1','
        SELECT DISTINCT
        qrsi.item_name
        FROM
        quality_report_sample qrs
        LEFT JOIN quality_report qr ON qrs.report_id = qr."id"
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrs."id" = qrsi.report_sample_id
        WHERE
        qrs.test_standard_no = ''' ||#{queryDTO.testStandardNo}||'''
        AND qr.report_type = ''' ||#{queryDTO.testType}||'''
        <if test="queryDTO.partId != null">
            AND qap.part_id = ${queryDTO.partId}
        </if>
        <if test="queryDTO.partBatchNo != null and queryDTO.partBatchNo != ''">
            AND qap.lot_batch_no LIKE ''' ||#{queryDTO.partBatchNo}||'''
        </if>
        ' )  AS ( ${itemName} )
    </select>
 
    <select id="getResultListV2" resultType="com.alibaba.fastjson.JSONObject">
        SELECT
        *
        FROM
        crosstab ( 'SELECT
        qap."id",
        qap.is_qualified,
        qap.lot_batch_no,
        qap.check_length,
        qap.scrap_arrived,
        qap.part_no,
        qap.part_desc,
        qap.replace_part_no,
        qap.replace_part_name,
        qap.examiner,
        qap.measuring_instrument,
        qr.check_time,
        qr.report_person,
        qr.report_type,
        bw."name" workstation_name,
        qrsi.item_name,
        qrsi.item_value
        FROM
        quality_report qr
        LEFT JOIN quality_report_sample qrs ON qr."id" = qrs.report_id
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrsi.report_sample_id = qrs."id"
        LEFT JOIN production_product_output ppo ON qap.system_no = ppo.system_no
        LEFT JOIN production_product_main ppm ON ppo.product_main_id = ppm."id"
        LEFT JOIN production_operation_task pot ON ppm.operation_task_id = pot."id"
        LEFT JOIN basic_workstation bw ON ppm.workstation_id = bw."id"
        WHERE qrs.test_standard_no =''' ||#{queryDTO.testStandardNo}|| ''' AND qr.report_type =''' ||#{queryDTO.testType}||'''
        <if test="queryDTO.startTime!=null and queryDTO.startTime!='' "> and qr.check_time >= ''' ||#{queryDTO.startTime} </if>
        <if test="queryDTO.endTime!=null and queryDTO.endTime!='' ">  ||''' and ''' ||#{queryDTO.endTime}||''' >= qr.check_time </if>
        <if test="queryDTO.partBatchNo!=null and queryDTO.partBatchNo!='' "> and qap.lot_batch_no LIKE ''' ||#{queryDTO.partBatchNo}||'''</if>
        <if test="queryDTO.partId != null"> and qap.part_id = ${queryDTO.partId} </if>
        <if test="queryDTO.workstationIds != null and queryDTO.workstationIds != ''">
            and bw."id" in (  ${queryDTO.workstationIds}  )
        </if>
        <if test="queryDTO.isQualified!=null "> and qap.is_qualified is ${queryDTO.isQualified}</if> order by 1','
        SELECT DISTINCT
        qrsi.item_name
        FROM
        quality_report_sample qrs
        LEFT JOIN quality_report qr ON qrs.report_id = qr."id"
        LEFT JOIN quality_apply_part qap ON qap.report_id = qr."id"
        LEFT JOIN quality_report_sample_item qrsi ON qrs."id" = qrsi.report_sample_id
        WHERE
        qrs.test_standard_no = ''' ||#{queryDTO.testStandardNo}||'''
        AND qr.report_type = ''' ||#{queryDTO.testType}||'''
        <if test="queryDTO.partId != null">
            AND qap.part_id = ${queryDTO.partId}
        </if>
        <if test="queryDTO.partBatchNo != null and queryDTO.partBatchNo != ''">
            AND qap.lot_batch_no LIKE ''' ||#{queryDTO.partBatchNo}||'''
        </if>
        ' )  AS ( ${itemName} )
    </select>
</mapper>