PiolotTH_ReportFrom/派诺报表SQL文件/订单未发货明细表插入数据SQL.sql
李狗蛋 470016f428 1
2025-06-03 13:44:45 +08:00

86 lines
3.5 KiB
Transact-SQL

CREATE PROCEDURE GZTH_DDWFHMXB
@FSDate nvarchar(1000),
@FEDate nvarchar(1000),
@FSaleOrgId nvarchar(1000)
AS
BEGIN
DECLARE @ConvertedDate DATE;
SET @ConvertedDate = CONVERT(DATE, @FEDate, 120);
-- 在日期上加一天
SET @ConvertedDate = DATEADD(DAY, 1, @ConvertedDate);
TRUNCATE TABLE GZ_DDWFHMX_TH
SELECT
A.FID AS FID,
AE.FENTRYID AS FENTRYID,
A.FApproveDate AS '日期',
B.FNAME AS '制单人',
ACG.区域 AS '区域',
G.FNAME AS '业务员',
A.F_contractnumber AS '合同号',
F.FNAME AS '客户',
H.FNAME AS '项目名',
WL.FNUMBER AS '物料编码',
WL_L.FNAME AS '物料名称',
WL_L.FSpecification AS '规格型号',
AE.FQTY AS '数量',
AE_F.FTaxPrice AS '含税单价',
AE_F.FALLAMOUNT_LC AS '价税合计',
HT_L.FDATAVALUE AS '合同类型',
A.F_Deliveryconditions AS '发货条件'
INTO #TEMP1
FROM T_SAL_ORDER A
INNER JOIN T_SEC_USER B ON A.FCreatorId = B.FUSERID --用户表
INNER JOIN V_BD_SALESMAN_L G ON G.FID = A.FSALERID -- 员工表,销售订单
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACG ON ACG.名称=G.FNAME --销售订单业务员区域
INNER JOIN T_BD_CUSTOMER_L F ON F.FCUSTID = A.FCustId --客户表
INNER JOIN T_BAS_PREBDONE_L H ON H.FID = A.F_projectname --工程项目名称表
INNER JOIN T_SAL_ORDERENTRY AE ON AE.FID = A.FID --销售订单明细表
INNER JOIN T_BD_MATERIAL WL ON WL.FMATERIALID = AE.FMaterialId --物料表
INNER JOIN T_BD_MATERIAL_L WL_L ON WL_L.FMATERIALID = WL.FMATERIALID --物料_L表
INNER JOIN T_SAL_ORDERENTRY_F AE_F ON AE_F.FENTRYID = AE.FENTRYID --销售订单明细-财务表
INNER JOIN T_BAS_ASSISTANTDATAENTRY_L HT_L On A.F_Ordercategory = HT_L.FENTRYID --合同类型辅助资料_L表
WHERE A.FDocumentStatus = 'C'
AND (ISNULL(@FSaleOrgId,'') = '' OR A.FSaleOrgId = @FSaleOrgId)
AND (ISNULL(@FSDate,'') = '' OR A.FAPPROVEDATE >= @FSDate)
AND (ISNULL(@FEDate,'') = '' OR A.FAPPROVEDATE < @ConvertedDate)
INSERT INTO GZ_DDWFHMX_TH([FId],[FENTRYID],[日期],[制单人],[区域],[业务员],[合同号],[客户],[项目名],
[物料编码],[物料名称],[规格型号],[数量],[含税单价],[价税合计],[合同类型],[发货条件])
SELECT * FROM #TEMP1
SELECT
E.FID AS FID,
D.FENTRYID AS FENTRYID,
SUM(B.FQTY) AS '已发货数量',
SUM(BF.FAllAmount_LC) AS '已发货金额'
INTO #TEMP2
FROM T_SAL_DELIVERYNOTICE A
INNER JOIN T_SAL_DELIVERYNOTICEENTRY B ON A.FID = B.FID
INNER JOIN T_SAL_DELIVERYNOTICEENTRY_F BF ON BF.FENTRYID = B.FENTRYID
INNER JOIN T_SAL_DELIVERYNOTICEENTRY_LK C ON B.FENTRYID = C.FENTRYID AND C.FSTABLENAME = 'T_SAL_ORDERENTRY'
INNEr JOIN T_SAL_ORDERENTRY D ON C.FSID = D.FENTRYID
INNER JOIN T_SAL_ORDER E ON D.FID = E.FID
WHERE
A.FDOCUMENTSTATUS = 'C'
AND (ISNULL(@FSaleOrgId,'') = '' OR E.FSaleOrgId = @FSaleOrgId)
AND(ISNULL(@FSDate,'') = '' OR E.FAPPROVEDATE >= @FSDate)
AND (ISNULL(@FEDate,'') = '' OR E.FAPPROVEDATE <= @ConvertedDate)
GROUP BY E.FID,D.FENTRYID
UPDATE A
SET A.[已发货数量] = B.[已发货数量],A.[已发货金额] = B.[已发货金额]
FROM GZ_DDWFHMX_TH A
INNER JOIN #TEMP2 B ON A.FId = B.FID AND A.FENTRYID = B.FENTRYID
UPDATE A
SET A.[未发货数量] = ISNULL(A.[数量],0) - ISNULL(A.[已发货数量],0),A.[未发货金额] = B.FALLAMOUNT_LC - ISNULL(A.[已发货金额],0)
FROM GZ_DDWFHMX_TH A
INNER JOIN T_SAL_ORDERENTRY_F B ON A.FENTRYID = B.FENTRYID
DROP TABLE #TEMP1,#TEMP2
END;