You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 
 

1043 lines
44 KiB

<?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.gaotao.modules.check.mapper.PhysicalInventoryMapper">
<!-- rqrq - 查询盘点主表列表(分页)-->
<select id="searchCountHeaderList" resultType="CountHeaderData">
SELECT
h.id,
h.site,
h.count_no AS countNo,
h.count_type AS countType,
h.status,
h.count_percent AS countPercent,
h.apply_user AS applyUser,
h.apply_date AS applyDate,
h.release_user AS releaseUser,
h.release_date AS releaseDate,
h.complete_user AS completeUser,
h.complete_date AS completeDate,
h.remark,
h.created_by AS createdBy,
h.created_date AS createdDate,
h.modified_by AS modifiedBy,
h.modified_date AS modifiedDate,
CASE h.count_type
WHEN 'CYCLE' THEN '循环盘点'
WHEN 'MANUAL' THEN '手工盘点'
ELSE h.count_type
END AS countTypeDesc,
CASE h.status
WHEN 'DRAFT' THEN '草稿'
WHEN 'RELEASED' THEN '已下达'
WHEN 'CHECKING' THEN '盘点中'
WHEN 'APPROVED' THEN '已审批'
WHEN 'COMPLETED' THEN '已完成'
WHEN 'CANCELLED' THEN '已取消'
ELSE h.status
END AS statusDesc,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no) AS totalLabelCount,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedLabelCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no) AS totalPalletCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedPalletCount
FROM count_header h
WHERE h.site = #{query.site}
<if test="query.searchCountNo != null and query.searchCountNo != ''">
AND h.count_no LIKE '%' + #{query.searchCountNo} + '%'
</if>
<if test="query.searchCountType != null and query.searchCountType != ''">
AND h.count_type = #{query.searchCountType}
</if>
<if test="query.searchStatus != null and query.searchStatus != ''">
AND h.status = #{query.searchStatus}
</if>
<if test="query.startDate != null">
AND h.apply_date &gt;= #{query.startDate}
</if>
<if test="query.endDate != null">
AND h.apply_date &lt;= DATEADD(day, 1, #{query.endDate})
</if>
ORDER BY h.created_date DESC
</select>
<!-- rqrq - 根据site和countNo查询盘点主表 -->
<select id="getCountHeaderByNo" resultType="CountHeaderData">
SELECT
h.id,
h.site,
h.count_no AS countNo,
h.count_type AS countType,
h.status,
h.count_percent AS countPercent,
h.apply_user AS applyUser,
h.apply_date AS applyDate,
h.release_user AS releaseUser,
h.release_date AS releaseDate,
h.complete_user AS completeUser,
h.complete_date AS completeDate,
h.remark,
h.created_by AS createdBy,
h.created_date AS createdDate,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no) AS totalLabelCount,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedLabelCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no) AS totalPalletCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedPalletCount
FROM count_header h
WHERE h.site = #{site} AND h.count_no = #{countNo}
</select>
<!-- rqrq - 检查是否存在活动状态的盘点单(草稿、已下达、盘点中) -->
<select id="checkActiveCountExists" resultType="CountHeaderData">
SELECT TOP 1
h.site,
h.count_no AS countNo,
h.count_type AS countType,
h.status,
CASE h.status WHEN 'DRAFT' THEN '草稿' WHEN 'RELEASED' THEN '已下达' WHEN 'CHECKING' THEN '盘点中' WHEN 'APPROVED' THEN '已审批' ELSE h.status END AS statusDesc
FROM count_header h
WHERE h.site = #{site} AND h.status IN ('DRAFT', 'RELEASED', 'CHECKING', 'APPROVED')
ORDER BY h.created_date DESC
</select>
<!-- rqrq - 获取当前活动的盘点单(草稿、已下达、盘点中) -->
<select id="getCurrentActiveCount" resultType="CountHeaderData">
SELECT
h.id,
h.site,
h.count_no AS countNo,
h.count_type AS countType,
h.status,
h.count_percent AS countPercent,
h.apply_user AS applyUser,
h.apply_date AS applyDate,
h.release_user AS releaseUser,
h.release_date AS releaseDate,
h.complete_user AS completeUser,
h.complete_date AS completeDate,
h.remark,
h.created_by AS createdBy,
h.created_date AS createdDate,
CASE h.count_type WHEN 'CYCLE' THEN '循环盘点' WHEN 'MANUAL' THEN '手工盘点' ELSE h.count_type END AS countTypeDesc,
CASE h.status WHEN 'DRAFT' THEN '草稿' WHEN 'RELEASED' THEN '已下达' WHEN 'CHECKING' THEN '盘点中' WHEN 'APPROVED' THEN '已审批' WHEN 'COMPLETED' THEN '已完成' WHEN 'CANCELLED' THEN '已取消' ELSE h.status END AS statusDesc,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no) AS totalLabelCount,
(SELECT COUNT(1) FROM count_label WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedLabelCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no) AS totalPalletCount,
(SELECT COUNT(1) FROM count_pallet WHERE site = h.site AND count_no = h.count_no AND count_flag = 'Y') AS checkedPalletCount
FROM count_header h
WHERE h.site = #{site} AND h.status IN ('DRAFT', 'RELEASED', 'CHECKING','APPROVED')
ORDER BY h.created_date DESC
</select>
<!-- rqrq - 生成盘点单号 -->
<select id="generateCountNo" resultType="String">
SELECT #{prefix} + RIGHT('0000' + CAST(ISNULL(MAX(CAST(RIGHT(count_no, 4) AS INT)), 0) + 1 AS VARCHAR), 4)
FROM count_header
WHERE site = #{site} AND count_no LIKE #{prefix} + '%'
</select>
<!-- rqrq - 查询盘点标签明细列表 -->
<select id="searchCountLabelList" resultType="CountLabelData">
SELECT
l.id,
l.site,
l.count_no AS countNo,
l.unit_id AS unitId,
l.part_no AS partNo,
l.qty,
l.batch_no AS batchNo,
l.location_id AS locationId,
l.warehouse_id AS warehouseId,
l.wdr,
l.pallet_id AS palletId,
l.label_type AS labelType,
l.count_flag AS countFlag,
l.count_date AS countDate,
l.count_user AS countUser,
l.created_by AS createdBy,
l.created_date AS createdDate,
h.part_desc AS partDesc,
w.WareHouseName AS warehouseName,
loc.LocationName AS locationName,
s.station_area AS stationArea,
s.station_id AS stationId,
ISNULL(s.location_z, 1) AS locationZ,
pd.position,
pd.layer,
h.height,
h.receive_date AS receiveDate,
h.last_count_date AS lastCountDate,
CASE l.label_type
WHEN 'ASSIGNED' THEN '指定物料'
WHEN 'EXTRA' THEN '同托盘关联'
ELSE l.label_type
END AS labelTypeDesc,
CASE l.count_flag
WHEN 'Y' THEN '已盘点'
WHEN 'N' THEN '未盘点'
ELSE l.count_flag
END AS countFlagDesc
FROM count_label l
LEFT JOIN handling_unit h ON l.unit_id = h.unit_id AND l.site = h.site
LEFT JOIN warehouse w ON l.warehouse_id = w.WareHouseID AND l.site = w.Site
LEFT JOIN location loc ON l.location_id = loc.LocationID AND l.site = loc.Site
LEFT JOIN pallet_detail pd ON l.unit_id = pd.serial_no AND l.site = pd.site
LEFT JOIN pallet p ON pd.pallet_id = p.pallet_id AND pd.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE l.site = #{query.site} AND l.count_no = #{query.countNo}
<if test="query.searchPalletId != null and query.searchPalletId != ''">
AND l.pallet_id LIKE '%' + #{query.searchPalletId} + '%'
</if>
<if test="query.searchPartNo != null and query.searchPartNo != ''">
AND l.part_no LIKE '%' + #{query.searchPartNo} + '%'
</if>
<if test="query.searchCountFlag != null and query.searchCountFlag != ''">
AND l.count_flag = #{query.searchCountFlag}
</if>
ORDER BY l.pallet_id, l.unit_id
</select>
<!-- rqrq - 批量插入盘点标签 -->
<insert id="batchInsertCountLabel">
INSERT INTO count_label (site, count_no, unit_id, part_no, qty, batch_no, location_id, warehouse_id, wdr, pallet_id, label_type, count_flag, created_by, created_date)
VALUES
<foreach collection="list" item="item" separator=",">
(#{item.site}, #{item.countNo}, #{item.unitId}, #{item.partNo}, #{item.qty}, #{item.batchNo},
#{item.locationId}, #{item.warehouseId}, #{item.wdr}, #{item.palletId}, #{item.labelType},
#{item.countFlag}, #{item.createdBy}, GETDATE())
</foreach>
</insert>
<!-- rqrq - 更新标签盘点状态 -->
<update id="updateCountLabelFlag">
UPDATE count_label
SET count_flag = #{countFlag},
count_date = GETDATE(),
count_user = #{countUser}
WHERE site = #{site} AND count_no = #{countNo} AND unit_id = #{unitId}
</update>
<!-- rqrq - 查询盘点栈板明细列表 -->
<select id="searchCountPalletList" resultType="CountPalletData">
SELECT
pp.id,
pp.site,
pp.count_no AS countNo,
pp.seq_no AS seqNo,
pp.pallet_id AS palletId,
pp.count_flag AS countFlag,
pp.label_count AS labelCount,
pp.checked_count AS checkedCount,
pp.count_date AS countDate,
pp.count_user AS countUser,
pp.created_by AS createdBy,
pp.created_date AS createdDate,
pp.location_z AS locationZ,
p.location_code AS locationCode,
s.station_code AS stationCode,
s.station_area AS stationArea,
s.station_id AS stationId,
CASE
WHEN pp.label_count > 0 THEN CAST(CAST(pp.checked_count AS FLOAT) / pp.label_count * 100 AS VARCHAR) + '%'
ELSE '0%'
END AS progressPercent,
CASE pp.count_flag
WHEN 'Y' THEN '已盘点'
WHEN 'N' THEN '未盘点'
ELSE pp.count_flag
END AS countFlagDesc
FROM count_pallet pp
LEFT JOIN pallet p ON pp.pallet_id = p.pallet_id AND pp.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE pp.site = #{query.site} AND pp.count_no = #{query.countNo}
<if test="query.searchPalletId != null and query.searchPalletId != ''">
AND pp.pallet_id LIKE '%' + #{query.searchPalletId} + '%'
</if>
<if test="query.searchCountFlag != null and query.searchCountFlag != ''">
AND pp.count_flag = #{query.searchCountFlag}
</if>
ORDER BY pp.seq_no
</select>
<!-- rqrq - 批量插入盘点栈板 -->
<insert id="batchInsertCountPallet">
INSERT INTO count_pallet (site, count_no, seq_no, pallet_id, count_flag, label_count, checked_count, location_z, created_by, created_date)
VALUES
<foreach collection="list" item="item" separator=",">
(#{item.site}, #{item.countNo}, #{item.seqNo}, #{item.palletId}, #{item.countFlag},
#{item.labelCount}, #{item.checkedCount}, #{item.locationZ}, #{item.createdBy}, GETDATE())
</foreach>
</insert>
<!-- rqrq - 更新栈板已盘点数量 -->
<update id="updateCountPalletCheckedCount">
UPDATE count_pallet
SET checked_count = (SELECT COUNT(1) FROM count_label WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId} AND count_flag = 'Y'),
count_flag = CASE
WHEN (SELECT COUNT(1) FROM count_label WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId} AND count_flag = 'Y') >= label_count THEN 'Y'
ELSE 'N'
END,
count_date = CASE
WHEN (SELECT COUNT(1) FROM count_label WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId} AND count_flag = 'Y') >= label_count THEN GETDATE()
ELSE count_date
END,
count_user = #{countUser}
WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</update>
<!-- rqrq - 检查栈板是否已存在 -->
<select id="checkCountPalletExists" resultType="int">
SELECT COUNT(1) FROM count_pallet WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</select>
<!-- rqrq - 获取当前最大序号 -->
<select id="getMaxSeqNo" resultType="Integer">
SELECT ISNULL(MAX(seq_no), 0) FROM count_pallet WHERE site = #{site} AND count_no = #{countNo}
</select>
<!-- rqrq - 查询盘点结果列表(包含diff_qty、handle_flag、handle_type字段)-->
<select id="searchCountResultList" resultType="CountResultData">
SELECT
r.id,
r.site,
r.count_no AS countNo,
r.unit_id AS unitId,
r.part_no AS partNo,
r.qty,
r.batch_no AS batchNo,
r.location_id AS locationId,
r.warehouse_id AS warehouseId,
r.wdr,
r.pallet_id AS palletId,
r.count_date AS countDate,
r.count_user AS countUser,
r.count_result AS countResult,
r.diff_qty AS diffQty,
r.handle_flag AS handleFlag,
r.handle_type AS handleType,
r.remark,
r.created_by AS createdBy,
r.created_date AS createdDate,
h.part_desc AS partDesc,
w.WareHouseName AS warehouseName,
loc.LocationName AS locationName,
CASE r.count_result
WHEN 'OK' THEN '正常'
WHEN 'MISSING' THEN '缺失'
WHEN 'SURPLUS' THEN '盈余'
WHEN 'QTY_DIFF' THEN '数量差异'
ELSE r.count_result
END AS countResultDesc,
CASE r.handle_flag
WHEN 'Y' THEN '已处理'
WHEN 'N' THEN '未处理'
ELSE '未处理'
END AS handleFlagDesc,
CASE r.handle_type
WHEN 'MANUAL' THEN '人工处理'
WHEN 'SYSTEM' THEN '系统处理'
ELSE ''
END AS handleTypeDesc
FROM count_result r
LEFT JOIN handling_unit h ON r.unit_id = h.unit_id AND r.site = h.site
LEFT JOIN warehouse w ON r.warehouse_id = w.WareHouseID AND r.site = w.Site
LEFT JOIN location loc ON r.location_id = loc.LocationID AND r.site = loc.Site
WHERE r.site = #{query.site} AND r.count_no = #{query.countNo}
<if test="query.searchPalletId != null and query.searchPalletId != ''">
AND r.pallet_id LIKE '%' + #{query.searchPalletId} + '%'
</if>
<if test="query.searchPartNo != null and query.searchPartNo != ''">
AND r.part_no LIKE '%' + #{query.searchPartNo} + '%'
</if>
<if test="query.searchCountResult != null and query.searchCountResult != ''">
AND r.count_result = #{query.searchCountResult}
</if>
ORDER BY r.count_date DESC, r.unit_id
</select>
<!-- rqrq - 插入盘点结果(包含diff_qty、handle_flag、handle_type字段)-->
<insert id="insertCountResult">
INSERT INTO count_result (site, count_no, unit_id, pallet_id, part_no, qty, batch_no, location_id, warehouse_id, wdr, count_date, count_user, count_result, diff_qty, handle_flag, handle_type, remark, created_by, created_date)
VALUES (#{result.site}, #{result.countNo}, #{result.unitId}, #{result.palletId}, #{result.partNo}, #{result.qty}, #{result.batchNo},
#{result.locationId}, #{result.warehouseId}, #{result.wdr},
GETDATE(), #{result.countUser}, #{result.countResult}, #{result.diffQty}, #{result.handleFlag}, #{result.handleType}, #{result.remark}, #{result.createdBy}, GETDATE())
</insert>
<!-- rqrq - 批量插入盘点结果(包含diff_qty、handle_flag、handle_type字段)-->
<insert id="batchInsertCountResult">
INSERT INTO count_result (site, count_no, unit_id, pallet_id, part_no, qty, batch_no, location_id, warehouse_id, wdr, count_date, count_user, count_result, diff_qty, handle_flag, handle_type, remark, created_by, created_date)
VALUES
<foreach collection="list" item="item" separator=",">
(#{item.site}, #{item.countNo}, #{item.unitId}, #{item.palletId}, #{item.partNo}, #{item.qty}, #{item.batchNo},
#{item.locationId}, #{item.warehouseId}, #{item.wdr},
GETDATE(), #{item.countUser}, #{item.countResult}, #{item.diffQty}, #{item.handleFlag}, #{item.handleType}, #{item.remark}, #{item.createdBy}, GETDATE())
</foreach>
</insert>
<!-- rqrq - 根据栈板查询盘点标签列表(用于RFID盘点比对)-->
<select id="getCountLabelsByPallet" resultType="CountLabelData">
SELECT
l.site,
l.count_no AS countNo,
l.unit_id AS unitId,
l.part_no AS partNo,
l.qty,
l.batch_no AS batchNo,
l.location_id AS locationId,
l.warehouse_id AS warehouseId,
l.wdr,
l.pallet_id AS palletId,
l.label_type AS labelType,
l.count_flag AS countFlag
FROM count_label l
WHERE l.site = #{site} AND l.count_no = #{countNo} AND l.pallet_id = #{palletId}
</select>
<!-- rqrq - 根据栈板批量更新盘点标签状态为已盘点 -->
<update id="updateCountLabelFlagByPallet">
UPDATE count_label
SET count_flag = 'Y',
count_date = GETDATE(),
count_user = #{countUser}
WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</update>
<!-- rqrq - 更新盘点栈板为已盘点 -->
<update id="updateCountPalletFlag">
UPDATE count_pallet
SET count_flag = 'Y',
count_date = GETDATE(),
count_user = #{countUser},
checked_count = label_count
WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</update>
<!-- rqrq - 根据标签号列表查询handling_unit信息 -->
<select id="getHandlingUnitsByUnitIdList" resultType="CountLabelData">
SELECT
h.site,
h.unit_id AS unitId,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.qty,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.wdr
FROM handling_unit h
WHERE h.site = #{site}
<if test="unitIdList != null and unitIdList.size() > 0">
AND h.unit_id IN
<foreach collection="unitIdList" item="item" open="(" separator="," close=")">
#{item}
</foreach>
</if>
</select>
<!-- rqrq - 根据栈板号查询pallet_detail的标签数据 -->
<select id="getPalletDetailByPalletId" resultType="CountLabelData">
SELECT
pd.site,
h.unit_id AS unitId,
pd.part_no AS partNo,
h.part_desc AS partDesc,
h.qty,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.wdr,
pd.pallet_id AS palletId
FROM pallet_detail pd
LEFT JOIN handling_unit h ON pd.site = h.site AND pd.serial_no = h.unit_id
WHERE pd.site = #{site} AND pd.pallet_id = #{palletId}
</select>
<!-- rqrq - 根据task_no和item_no查询盘点单号 -->
<select id="getCountNoByTask" resultType="String">
SELECT TOP 1 cp.count_no
FROM count_pallet cp
WHERE cp.site = #{site} AND cp.task_no = #{taskNo}
ORDER BY cp.created_date DESC
</select>
<!-- rqrq - 根据栈板删除盘点结果(重复调用时先删后插)-->
<delete id="deleteCountResultByPallet">
DELETE FROM count_result
WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</delete>
<!-- rqrq - 查询wms_order_task的状态 -->
<select id="getWmsOrderTaskStatus" resultType="String">
SELECT TOP 1 t.status
FROM wms_order_task t
WHERE t.site = #{site} AND t.task_no = #{taskNo}
</select>
<!-- rqrq - 根据taskNo和palletId更新wms_order_task_detail状态为已完成 -->
<update id="updateTaskDetailStatusByPallet">
UPDATE wms_order_task_detail
SET status = '已完成',
wms_status = '已盘点'
WHERE site = #{site} AND task_no = #{taskNo} AND pallet_id = #{palletId}
</update>
<!-- rqrq - 检查taskNo下所有明细是否都已完成 -->
<select id="checkAllTaskDetailCompletedByTaskNo" resultType="int">
SELECT COUNT(1)
FROM wms_order_task_detail
WHERE site = #{site} AND task_no = #{taskNo} AND status != '已完成'
</select>
<!-- rqrq - 更新wms_order_task主表状态为已完成 -->
<update id="updateTaskStatusCompleted">
UPDATE wms_order_task
SET status = '已完成',
updated_time = GETDATE()
WHERE site = #{site} AND task_no = #{taskNo}
</update>
<!-- rqrq - 根据盘点单号查询关联的任务单主表列表 -->
<select id="searchOrderTaskByCountNo" resultType="com.gaotao.modules.automatedWarehouse.entity.WmsOrderTaskData">
SELECT
t.site,
t.task_no AS taskNo,
t.item_no AS itemNo,
t.source_type AS sourceType,
t.source_bill_no AS sourceBillNo,
t.status,
t.created_by AS createdBy,
t.created_time AS createdTime
FROM wms_order_task t
WHERE t.site = #{site} AND t.source_bill_no = #{countNo}
ORDER BY t.created_time DESC
</select>
<!-- rqrq - 查询任务单明细列表 -->
<select id="searchOrderTaskDetail" resultType="com.gaotao.modules.automatedWarehouse.entity.WmsOrderTaskDetailData">
SELECT
d.site,
d.task_no AS taskNo,
d.item_no AS itemNo,
d.seq_no AS seqNo,
d.pallet_id AS palletId,
d.action_type AS actionType,
d.status,
d.wms_status AS wmsStatus,
d.from_location AS fromLocation,
d.to_location AS toLocation
FROM wms_order_task_detail d
WHERE d.site = #{site} AND d.task_no = #{taskNo}
ORDER BY d.seq_no
</select>
<!-- rqrq - 检查是否存在未完成的任务单 -->
<select id="countUncompletedTask" resultType="int">
SELECT COUNT(1)
FROM wms_order_task t
WHERE t.site = #{site}
AND t.source_bill_no = #{countNo}
AND t.status != '已完成'
</select>
<!-- rqrq - 检查未盘点的栈板数量 -->
<select id="countUncheckedPallet" resultType="int">
SELECT COUNT(1)
FROM count_pallet cp
WHERE cp.site = #{site}
AND cp.count_no = #{countNo}
AND (cp.count_flag IS NULL OR cp.count_flag != 'Y')
</select>
<!-- rqrq - 根据盘点结果批量更新handling_unit的count_flag和last_count_date -->
<update id="batchUpdateHandlingUnitCountFlagByCountNo">
UPDATE handling_unit WITH (ROWLOCK)
SET count_flag = 'Y',
last_count_date = #{countDate}
WHERE site = #{site}
AND unit_id IN (
SELECT cr.unit_id
FROM count_result cr
WHERE cr.site = #{site} AND cr.count_no = #{countNo}
)
</update>
<!-- rqrq - 根据栈板号查询盘点栈板信息(用于PDA手工盘点) -->
<select id="getCountPalletByPalletId" resultType="CountPalletData">
SELECT
cp.site,
cp.count_no AS countNo,
cp.pallet_id AS palletId,
cp.seq_no AS seqNo,
cp.label_count AS labelCount,
cp.checked_count AS checkedCount,
cp.count_flag AS countFlag,
cp.location_z AS locationZ
FROM count_pallet cp
WHERE cp.site = #{site} AND cp.pallet_id = #{palletId}
AND EXISTS (
SELECT 1 FROM count_header ch
WHERE ch.site = cp.site AND ch.count_no = cp.count_no AND ch.status = 'CHECKING'
)
</select>
<!-- rqrq - 根据栈板号查询盘点标签明细列表(用于PDA手工盘点) -->
<select id="getCountLabelsByPalletId" resultType="CountLabelData">
SELECT
cl.site,
cl.count_no AS countNo,
cl.unit_id AS unitId,
cl.part_no AS partNo,
h.part_desc AS partDesc,
cl.qty,
cl.batch_no AS batchNo,
cl.pallet_id AS palletId,
cl.count_flag AS countFlag,
CASE cl.count_flag WHEN 'Y' THEN '已盘点' ELSE '未盘点' END AS countFlagDesc
FROM count_label cl
LEFT JOIN handling_unit h ON h.site = cl.site AND h.unit_id = cl.unit_id
WHERE cl.site = #{site} AND cl.count_no = #{countNo} AND cl.pallet_id = #{palletId}
ORDER BY cl.unit_id
</select>
<!-- rqrq - 根据标签号查询标签信息(用于PDA扫描标签) -->
<select id="getLabelInfoByUnitId" resultType="CountLabelData">
SELECT
h.site,
h.unit_id AS unitId,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.qty,
h.batch_no AS batchNo,
h.wdr
FROM handling_unit h
WHERE h.site = #{site} AND h.unit_id = #{unitId}
</select>
<!-- rqrq - 查询物料汇总(按物料+批号+WDR+仓库+库位汇总)-->
<select id="searchMaterialSummary" resultType="CountMaterialSummary">
SELECT
l.site,
l.count_no AS countNo,
l.part_no AS partNo,
MAX(h.part_desc) AS partDesc,
l.batch_no AS batchNo,
l.wdr,
l.warehouse_id AS warehouseId,
MAX(w.WareHouseName) AS warehouseName,
l.location_id AS locationId,
MAX(loc.LocationName) AS locationName,
COUNT(1) AS labelCount,
SUM(l.qty) AS totalQty,
COUNT(DISTINCT l.pallet_id) AS palletCount,
SUM(CASE WHEN l.count_flag = 'Y' THEN 1 ELSE 0 END) AS checkedLabelCount,
CASE
WHEN COUNT(1) > 0 THEN CAST(CAST(SUM(CASE WHEN l.count_flag = 'Y' THEN 1 ELSE 0 END) AS FLOAT) / COUNT(1) * 100 AS VARCHAR) + '%'
ELSE '0%'
END AS progressPercent
FROM count_label l
LEFT JOIN handling_unit h ON l.unit_id = h.unit_id AND l.site = h.site
LEFT JOIN warehouse w ON l.warehouse_id = w.WareHouseID AND l.site = w.Site
LEFT JOIN location loc ON l.location_id = loc.LocationID AND l.site = loc.Site
WHERE l.site = #{query.site} AND l.count_no = #{query.countNo}
GROUP BY l.site, l.count_no, l.part_no, l.batch_no, l.wdr, l.warehouse_id, l.location_id
ORDER BY l.part_no, l.batch_no
</select>
<!-- rqrq - 查询立库内所有标签(用于循环盘点)-->
<select id="queryWarehouseLabels" resultType="CountLabelInfo">
SELECT
h.unit_id AS unitId,
h.site,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.qty,
h.in_stock_flag AS inStockFlag,
h.status,
h.status_db AS statusDb,
h.created_date AS createdDate,
h.created_by AS createdBy,
h.modified_date AS modifiedDate,
h.modified_by AS modifiedBy,
h.print_count AS printCount,
h.last_print_date AS lastPrintDate,
h.printer_name AS printerName,
h.qr_code AS qrCode,
h.bar_code AS barCode,
p.remark,
w.WareHouseName AS warehouseName,
l.LocationName AS locationName,
p.pallet_id AS palletId,
s.station_id AS stationId,
s.station_area AS stationArea,
h.height,
b.position,
b.layer,
p.calling_flag AS callingFlag,
h.receive_date AS receiveDate,
h.wdr,
h.last_count_date AS lastCountDate,
h.count_flag AS countFlag
FROM handling_unit h
LEFT JOIN warehouse w ON h.warehouse_id = w.WareHouseID AND h.site = w.Site
LEFT JOIN location l ON h.location_id = l.LocationID AND h.site = l.Site
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE h.site = #{site} AND p.pallet_id IS NOT NULL
</select>
<!-- rqrq - 查询立库内未盘点标签总数(count_flag不为Y的标签,且托盘在立库中)-->
<select id="countWarehouseLabels" resultType="int">
SELECT COUNT(1)
FROM handling_unit h
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
WHERE h.site = #{site} AND p.pallet_id IS NOT NULL
AND (h.count_flag IS NULL OR h.count_flag != 'Y')
AND p.wcs_location IS NOT NULL AND p.wcs_location != ''
</select>
<!-- rqrq - 按立库层数(location_z)统计未盘点标签分布(托盘在立库中)-->
<select id="countLabelsByLayer" resultType="LayerLabelCountResult">
SELECT
ISNULL(s.location_z, 1) AS locationZ,
COUNT(1) AS labelCount
FROM handling_unit h
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE h.site = #{site} AND p.pallet_id IS NOT NULL
AND (h.count_flag IS NULL OR h.count_flag != 'Y')
AND p.wcs_location IS NOT NULL AND p.wcs_location != ''
GROUP BY ISNULL(s.location_z, 1)
ORDER BY ISNULL(s.location_z, 1)
</select>
<!-- rqrq - 按立库层数(location_z)查询未盘点标签(用于循环盘点按层分布选取,托盘在立库中)-->
<select id="queryLabelsByLayer" resultType="CountLabelInfo">
SELECT
h.unit_id AS unitId,
h.site,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.qty,
p.pallet_id AS palletId,
h.receive_date AS receiveDate,
h.wdr,
h.last_count_date AS lastCountDate,
h.count_flag AS countFlag,
w.WareHouseName AS warehouseName,
l.LocationName AS locationName,
ISNULL(s.location_z, 1) AS locationZ,
p.location_code AS locationCode
FROM handling_unit h
LEFT JOIN warehouse w ON h.warehouse_id = w.WareHouseID AND h.site = w.Site
LEFT JOIN location l ON h.location_id = l.LocationID AND h.site = l.Site
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE h.site = #{site} AND p.pallet_id IS NOT NULL
AND (h.count_flag IS NULL OR h.count_flag != 'Y')
AND p.wcs_location IS NOT NULL AND p.wcs_location != ''
ORDER BY ISNULL(s.location_z, 1), p.pallet_id, ISNULL(h.last_count_date, h.receive_date) ASC
</select>
<!-- rqrq - 按托盘分组查询标签(按上次盘点日期或接收日期排序)-->
<select id="queryLabelsByPalletOrder" resultType="CountLabelInfo">
SELECT
h.unit_id AS unitId,
h.site,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.qty,
p.pallet_id AS palletId,
h.receive_date AS receiveDate,
h.wdr,
h.last_count_date AS lastCountDate,
h.count_flag AS countFlag,
w.WareHouseName AS warehouseName,
l.LocationName AS locationName
FROM handling_unit h
LEFT JOIN warehouse w ON h.warehouse_id = w.WareHouseID AND h.site = w.Site
LEFT JOIN location l ON h.location_id = l.LocationID AND h.site = l.Site
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
WHERE h.site = #{site} AND p.pallet_id IS NOT NULL
ORDER BY p.pallet_id, ISNULL(h.last_count_date, h.receive_date) ASC
</select>
<!-- rqrq - 查询指定物料的标签(手工盘点)-->
<select id="queryLabelsByMaterial" resultType="CountLabelInfo">
SELECT
h.unit_id AS unitId,
h.site,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.qty,
p.pallet_id AS palletId,
h.receive_date AS receiveDate,
h.wdr,
h.last_count_date AS lastCountDate,
h.count_flag AS countFlag,
w.WareHouseName AS warehouseName,
l.LocationName AS locationName,
ISNULL(s.location_z, 1) AS locationZ,
p.location_code AS locationCode
FROM handling_unit h
LEFT JOIN warehouse w ON h.warehouse_id = w.WareHouseID AND h.site = w.Site
LEFT JOIN location l ON h.location_id = l.LocationID AND h.site = l.Site
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE h.site = #{query.site} AND p.pallet_id IS NOT NULL
<if test="query.searchPartNo != null and query.searchPartNo != ''">
AND h.part_no LIKE '%' + #{query.searchPartNo} + '%'
</if>
<if test="query.searchBatchNo != null and query.searchBatchNo != ''">
AND h.batch_no LIKE '%' + #{query.searchBatchNo} + '%'
</if>
<if test="query.searchWdr != null and query.searchWdr != ''">
AND h.wdr LIKE '%' + #{query.searchWdr} + '%'
</if>
ORDER BY h.part_no, h.batch_no, p.pallet_id
</select>
<!-- rqrq - 查询同托盘的其他标签 -->
<select id="queryExtraLabelsByPallet" resultType="CountLabelInfo">
SELECT
h.unit_id AS unitId,
h.site,
h.part_no AS partNo,
h.part_desc AS partDesc,
h.batch_no AS batchNo,
h.location_id AS locationId,
h.warehouse_id AS warehouseId,
h.qty,
p.pallet_id AS palletId,
h.receive_date AS receiveDate,
h.wdr,
h.last_count_date AS lastCountDate,
h.count_flag AS countFlag,
ISNULL(s.location_z, 1) AS locationZ,
p.location_code AS locationCode
FROM handling_unit h
LEFT JOIN pallet_detail b ON h.unit_id = b.serial_no AND h.site = b.site
LEFT JOIN pallet p ON b.pallet_id = p.pallet_id AND b.site = p.site
LEFT JOIN agv_station s ON p.location_code = s.station_code
WHERE h.site = #{site} AND p.pallet_id = #{palletId}
<if test="excludeUnitIds != null and excludeUnitIds.size() > 0">
AND h.unit_id NOT IN
<foreach collection="excludeUnitIds" item="unitId" open="(" separator="," close=")">
#{unitId}
</foreach>
</if>
</select>
<!-- rqrq - 更新handling_unit盘点状态 -->
<update id="updateHandlingUnitCountFlag">
UPDATE handling_unit
SET count_flag = #{countFlag},
last_count_date = GETDATE()
WHERE site = #{site} AND unit_id = #{unitId}
</update>
<!-- rqrq - 更新盘点主表状态 -->
<update id="updateCountHeaderStatus">
UPDATE count_header
SET status = #{header.status},
modified_by = #{header.modifiedBy},
modified_date = GETDATE()
<if test="header.releaseUser != null">
, release_user = #{header.releaseUser}
, release_date = GETDATE()
</if>
<if test="header.completeUser != null">
, complete_user = #{header.completeUser}
, complete_date = GETDATE()
</if>
WHERE site = #{header.site} AND count_no = #{header.countNo}
</update>
<!-- rqrq - 插入盘点主表 -->
<insert id="insertCountHeader">
INSERT INTO count_header (site, count_no, count_type, status, count_percent, apply_user, apply_date, remark, created_by, created_date)
VALUES (#{header.site}, #{header.countNo}, #{header.countType}, #{header.status}, #{header.countPercent},
#{header.applyUser}, GETDATE(), #{header.remark}, #{header.createdBy}, GETDATE())
</insert>
<!-- rqrq - 删除盘点主表 -->
<delete id="deleteCountHeader">
DELETE FROM count_header WHERE site = #{site} AND count_no = #{countNo}
</delete>
<!-- rqrq - 删除盘点标签子表 -->
<delete id="deleteCountLabel">
DELETE FROM count_label WHERE site = #{site} AND count_no = #{countNo}
</delete>
<!-- rqrq - 删除盘点栈板子表 -->
<delete id="deleteCountPallet">
DELETE FROM count_pallet WHERE site = #{site} AND count_no = #{countNo}
</delete>
<!-- ==================== 推送WCS相关 ==================== -->
<!-- rqrq - 查询未推送的栈板列表(按层均匀分布排序)-->
<select id="queryUnpushedPallets" resultType="CountPalletData">
SELECT
pp.id,
pp.site,
pp.count_no AS countNo,
pp.seq_no AS seqNo,
pp.pallet_id AS palletId,
pp.count_flag AS countFlag,
pp.label_count AS labelCount,
pp.checked_count AS checkedCount,
pp.location_z AS locationZ,
pp.task_no AS taskNo,
p.location_code AS locationCode
FROM count_pallet pp
LEFT JOIN pallet p ON pp.pallet_id = p.pallet_id AND pp.site = p.site
WHERE pp.site = #{site}
AND pp.count_no = #{countNo}
AND (pp.task_no IS NULL OR pp.task_no = '')
ORDER BY pp.location_z, pp.seq_no
</select>
<!-- rqrq - 更新栈板推送状态 -->
<update id="updatePalletPushStatus">
UPDATE count_pallet
SET task_no = #{taskNo}
WHERE site = #{site}
AND count_no = #{countNo}
AND pallet_id = #{palletId}
</update>
<!-- rqrq - 查询盘点单的盘点类型 -->
<select id="getCountType" resultType="java.lang.String">
SELECT count_type FROM count_header WHERE site = #{site} AND count_no = #{countNo}
</select>
<!-- rqrq - 根据栈板号查询关联的任务单号 -->
<select id="getTaskNoByPallet" resultType="java.lang.String">
SELECT task_no
FROM count_pallet
WHERE site = #{site} AND count_no = #{countNo} AND pallet_id = #{palletId}
</select>
<!-- rqrq - 检查未处理的异常盘点结果数量(用于完成盘点单校验) -->
<select id="countUnhandledExceptionResult" resultType="int">
SELECT COUNT(1)
FROM count_result cr
WHERE cr.site = #{site}
AND cr.count_no = #{countNo}
AND cr.count_result != 'OK'
AND (cr.handle_flag IS NULL OR cr.handle_flag = 'N')
</select>
<!-- rqrq - 查询未处理的异常盘点结果 -->
<select id="searchUnhandledExceptionList" resultType="CountResultData">
SELECT
r.id,
r.site,
r.count_no AS countNo,
r.unit_id AS unitId,
r.part_no AS partNo,
r.qty,
r.batch_no AS batchNo,
r.location_id AS locationId,
r.warehouse_id AS warehouseId,
r.wdr,
r.pallet_id AS palletId,
r.count_date AS countDate,
r.count_user AS countUser,
r.count_result AS countResult,
r.diff_qty AS diffQty,
r.handle_flag AS handleFlag,
r.handle_type AS handleType,
r.remark,
r.created_by AS createdBy,
r.created_date AS createdDate,
h.part_desc AS partDesc,
w.WareHouseName AS warehouseName,
loc.LocationName AS locationName,
CASE r.count_result
WHEN 'OK' THEN '正常'
WHEN 'MISSING' THEN '缺失'
WHEN 'SURPLUS' THEN '盈余'
WHEN 'QTY_DIFF' THEN '数量差异'
ELSE r.count_result
END AS countResultDesc,
CASE r.handle_flag
WHEN 'Y' THEN '已处理'
WHEN 'N' THEN '未处理'
ELSE '未处理'
END AS handleFlagDesc
FROM count_result r
LEFT JOIN handling_unit h ON r.unit_id = h.unit_id AND r.site = h.site
LEFT JOIN warehouse w ON r.warehouse_id = w.WareHouseID AND r.site = w.Site
LEFT JOIN location loc ON r.location_id = loc.LocationID AND r.site = loc.Site
WHERE r.site = #{query.site}
AND r.count_no = #{query.countNo}
AND r.count_result != 'OK'
AND (r.handle_flag IS NULL OR r.handle_flag = 'N')
ORDER BY r.count_result, r.unit_id
</select>
<!-- rqrq - 更新盘点结果的处理标记和处理方式 -->
<update id="updateCountResultHandleFlag">
UPDATE count_result
SET handle_type = #{handleType}
WHERE id = #{id}
<!-- AND site = #{site} -->
<!-- AND count_no = #{countNo}-->
</update>
<select id="getCountResultById" resultType="CountResultData">
select
id,site,count_no,unit_id,part_no,qty,batch_no,location_id,warehouse_id,wdr,pallet_id,count_date,count_user,count_result,
remark,created_by,created_date,diff_qty,handle_flag,handle_type
from count_result where id = #{id}
</select>
<update id="updateCountResultHandleFlagForId">
UPDATE count_result
SET handle_flag = #{handleFlag}
WHERE id = #{id}
</update>
<select id="getSysIfCount" resultType="String">
select dbo.Get_SysParamenter(#{site},10001)
</select>
<select id="getSysCountCycle" resultType="String">
select dbo.Get_SysParamenter(#{site},10002)
</select>
<update id="updateLastPandianHU">
update handling_unit set count_flag='N' where site=#{site} and count_flag='Y' and #{lastPandian}> isnull(last_count_date,'2000-01-01')
</update>
<update id="updateSysIfCount">
update sysParameters set paraValue=#{value} where site=#{site} and parameterId='10001'
</update>
<!-- rqrq - 统计该盘点单已有的任务单数量(用于计算流水号) -->
<select id="countOrderTaskByCountNo" resultType="int">
SELECT COUNT(1)
FROM wms_order_task WITH (NOLOCK)
WHERE site = #{site}
AND source_bill_no = #{countNo}
</select>
</mapper>