客户库存盘点明细优化sql

This commit is contained in:
mzr 2024-11-01 10:55:19 +08:00
parent 815d56abfb
commit 1cba03479c
3 changed files with 79 additions and 87 deletions

View File

@ -13,6 +13,29 @@
<result column="area_name" property="areaName" jdbcType="VARCHAR" />
</resultMap>
<!-- 日期查询条件 -->
<sql id="dateSel_a">
<if test="startDate != null and startDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &gt;=
TO_CHAR(TO_DATE(SUBSTR(#{startDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<if test="endDate != null and endDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &lt;=
TO_CHAR(TO_DATE(SUBSTR(#{endDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
</sql>
<!-- 日期查询条件 -->
<sql id="dateSel">
<if test="startDate != null and startDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &gt;=
TO_CHAR(TO_DATE(SUBSTR(#{startDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<if test="endDate != null and endDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &lt;=
TO_CHAR(TO_DATE(SUBSTR(#{endDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
</sql>
<!-- 客户库存盘点明细 -->
<select id="getClientStockReportSql" resultType="com.yb.lb.webapp.stock.entity.ClientStockReport" parameterType="map">
SELECT
@ -25,7 +48,26 @@
NVL(t1.count_num, 0) "countNum",
NVL(t1.goods_num, 0) "goodsNum",
NVL(t2.bill_num, 0) "billNum"
FROM crm_distributor_user_info t0
FROM ( SELECT
cdui.id,
cdui.uecode,
cdui.distributor_name,
cdui.ancestors,
cdui.marketing_area_id,
cdui.region,
cdui.service_id,
cdui.company_id
FROM (
SELECT client_id
FROM crm_inventory_info
WHERE confirm_status = '1'
<include refid="dateSel" />
GROUP BY client_id
) table_client
LEFT JOIN crm_distributor_user_info cdui ON table_client.client_id = cdui.id
WHERE cdui.status = '1' AND cdui.documents_status = '1'
AND cdui.uecode IS NOT NULL AND cdui.company_id = #{companyId}
) t0
LEFT JOIN (
SELECT *
FROM (
@ -41,14 +83,7 @@
FROM crm_inventory_info a
LEFT JOIN pd1 b ON a.id = b.bill_id
WHERE a.confirm_status = '1' AND a.company_id = #{companyId}
<if test="startDate != null and startDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &gt;=
TO_CHAR(TO_DATE(SUBSTR(#{startDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<if test="endDate != null and endDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &lt;=
TO_CHAR(TO_DATE(SUBSTR(#{endDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<include refid="dateSel_a" />
) tt1
) temp
WHERE rn = 1
@ -56,19 +91,11 @@
LEFT JOIN (SELECT client_id, COUNT(1) bill_num
FROM crm_inventory_info
WHERE confirm_status = '1' AND company_id = #{companyId}
<if test="startDate != null and startDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &gt;=
TO_CHAR(TO_DATE(SUBSTR(#{startDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<if test="endDate != null and endDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &lt;=
TO_CHAR(TO_DATE(SUBSTR(#{endDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<include refid="dateSel" />
GROUP BY client_id) t2 ON t0.id = t2.client_id
LEFT JOIN crm_servicer_user_info csui ON t0.service_id = csui.id
LEFT JOIN crm_marketing_area_info cmai ON t0.marketing_area_id = cmai.id
WHERE t0.status = '1' AND t0.documents_status = '1'
AND t0.uecode IS NOT NULL AND t0.company_id = #{companyId}
WHERE 1=1
<if test="clientId !=null and clientId !=''">
AND t0.id = #{clientId}
</if>
@ -171,7 +198,7 @@
</if>
</select>
<!-- 根据条件参数查询盘点子表列表 -->
<!-- 根据条件参数查询盘点子表的商品 -->
<select id="getClientInventoryDetail" resultType="map" parameterType="map">
SELECT a.goods_no AS "goodsNo",
b.goods_name AS "goodsName",
@ -187,4 +214,35 @@
LEFT JOIN crm_goods_info b ON a.goods_no = b.goods_no and b.company_id = #{companyId}
</select>
<!-- 查询日期区间内的产品库存明细 -->
<select id="findClientGoodsStockDetail" resultType="map" parameterType="map">
SELECT
nvl(t0.bill_date,'') AS "billDate",
nvl(t1.bill_no,'') AS "billNo",
nvl(t1.count_num, 0) AS "countNum",
nvl(t1.prod_date,'') AS "prodDate"
FROM (
SELECT
TO_CHAR(TO_DATE(#{startDate}, 'yyyy-MM-dd') + ROWNUM - 1, 'yyyy-MM-dd') AS bill_date
FROM DUAL
CONNECT BY ROWNUM &lt;= trunc(to_date( #{endDate}, 'yyyy-MM-dd') - to_date(#{startDate}, 'yyyy-MM-dd')) + 1
) t0 LEFT JOIN (
SELECT
a.bill_no, a.bill_date, a.count_num, a.prod_date
FROM crm_inventory_detail a
WHERE confirm_status = '1'
<include refid="dateSel_a" />
<if test="clientId != null and clientId != ''">
AND a.client_id = #{clientId}
</if>
<if test="goodsNo != null and goodsNo != ''">
AND a.goods_no = #{goodsNo}
</if>
<if test="companyId != null and companyId != ''">
AND a.company_id = #{companyId}
</if>
) t1 ON t0.bill_date = t1.bill_date
ORDER BY t0.bill_date
</select>
</mapper>

View File

@ -85,39 +85,6 @@
ORDER BY a.bill_date DESC,a.create_time DESC
</select>
<!-- 根据条件参数查询盘点子表列表 -->
<select id="findCrmInventoryDetail1" resultMap="crmInventoryDetailMap" parameterType="map">
SELECT
a.bill_no, a.bill_date, a.count_num, a.prod_date
FROM crm_inventory_detail a
<where>
<if test="billId != null and billId != ''">
AND a.bill_id = #{billId}
</if>
<if test="clientId != null and clientId != ''">
AND a.client_id = #{clientId}
</if>
<if test="confirmStatus != null and confirmStatus != ''">
AND a.confirm_status = #{confirmStatus}
</if>
<if test="goodsNo != null and goodsNo != ''">
AND a.goods_no = #{goodsNo}
</if>
<if test="companyId != null and companyId != ''">
AND a.company_id = #{companyId}
</if>
<if test="startDate != null and startDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &gt;=
TO_CHAR(TO_DATE(SUBSTR(#{startDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
<if test="endDate != null and endDate !=''">
AND TO_CHAR(TO_DATE(SUBSTR(a.bill_date,1,10),'yyyy-MM-dd'),'yyyy-MM-dd') &lt;=
TO_CHAR(TO_DATE(SUBSTR(#{endDate},1,10),'yyyy-MM-dd'),'yyyy-MM-dd')
</if>
</where>
ORDER BY a.bill_date, a.create_time
</select>
<!-- 根据条件参数合计数量 -->
<select id="sumCountNum" resultType="Double" parameterType="map">
SELECT NVL(SUM(count_num), 0) num FROM crm_inventory_detail

View File

@ -2,9 +2,7 @@ package com.yb.lb.webapp.stock.service;
import com.github.pagehelper.PageInfo;
import com.yb.lb.common.base.oracle.BaseOracleDao;
import com.yb.lb.common.utils.DateUtil;
import com.yb.lb.webapp.stock.entity.ClientStockReport;
import com.yb.lb.webapp.stock.entity.CrmInventoryDetail;
import org.springframework.beans.factory.annotation.Autowired;
import org.springframework.stereotype.Service;
@ -12,7 +10,6 @@ import java.util.ArrayList;
import java.util.HashMap;
import java.util.List;
import java.util.Map;
import java.util.stream.Collectors;
/**
* 盘点单
@ -54,41 +51,11 @@ public class ClientStockReportService {
public List listClientStockDetail(Map<String, Object> params) {
// 最后返回的数据
List<Map<String, Object>> list = new ArrayList<>();
// 查询日期范围内的日期
String startDate = params.getOrDefault("startDate", "") + "";
String endDate = params.getOrDefault("endDate", "") + "";
List<String> dateList = DateUtil.findDateList(startDate, endDate);
List<Map<String, Object>> goodsList = this.findList(params, ".getClientInventoryDetail");
for (Map<String, Object> goodsMap : goodsList) {
Map<String, Object> selMap = new HashMap<>(params);
selMap.put("goodsNo", goodsMap.get("goodsNo"));
selMap.put("confirmStatus", "1");
List<CrmInventoryDetail> detailList = inventoryInfoService.findDetailList(selMap, ".findCrmInventoryDetail1");
List<Map<String, Object>> pdList = new ArrayList<>();
for (String date : dateList) {
// 根据日期去寻找集合中匹配的值
List<CrmInventoryDetail> inventoryDetails = detailList.stream()
.filter(a -> date.equals(a.getBillDate())).collect(Collectors.toList());
if (inventoryDetails.size() > 0) {
for (CrmInventoryDetail inventoryDetail : inventoryDetails) {
Map<String, Object> oneMap = new HashMap<>();
oneMap.put("billNo", inventoryDetail.getBillNo());
oneMap.put("billDate", inventoryDetail.getBillDate());
oneMap.put("prodDate", inventoryDetail.getProdDate());
oneMap.put("countNum", inventoryDetail.getCountNum());
pdList.add(oneMap);
}
} else {
Map<String, Object> oneMap = new HashMap<>();
oneMap.put("billNo", "");
oneMap.put("billDate", date);
oneMap.put("prodDate", "");
oneMap.put("countNum", "0");
pdList.add(oneMap);
}
}
goodsMap.put("pdList", pdList);
goodsMap.put("pdList", this.findList(selMap, ".findClientGoodsStockDetail"));
list.add(goodsMap);
}
return list;