Piolot_RepotForm_PeiHao/特价明细表SQL.sql
2025-06-24 14:47:52 +08:00

860 lines
32 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

---过滤公司
SELECT A.FID AS FID
--INTO #TEMP3
FROM T_SAL_ORDER A
INNER JOIN T_BD_CUSTOMER_L C
ON C.FCUSTID = A.FCUSTID
AND C.FLOCALEID = 2052
LEFT JOIN V_BD_SALESMAN_L L
ON L.fid = A.FSALERID
LEFT JOIN T_PerformanceSharing M
ON M.FSOURCEBILLNO = A.FBILLNO
AND M.FDOCUMENTSTATUS = 'C'
LEFT JOIN T_PerformanceSharingEntry N
ON N.FID = M.FID
LEFT JOIN V_BD_SALESMAN_L O
ON O.fid = N.FSALEID
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO
ON ACO. = O.FNAME
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL
ON ACL. = L.FNAME
WHERE A.FSALEORGID = 100302
AND ACO. = '碳索智控'
OR ACL. = '碳索智控'
OR C.FNAME IN ( '派诺科技(香港)有限公司', '武汉派诺科技发展有限公司', '珠海华夏云联技术有限公司', '广东碳索智控科技有限公司', '武汉派诺科技发展有限公司', '珠海兴诺能源技术有限公司','广东诺瓦数能科技有限公司' )
OR L.FNAME = '兴诺总'
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') >= '2025-06-01 00:00:00'
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') <= '2025-06-20 00:00:00';
/*dialect*/
--- 取变更合同
SELECT *
INTO #TABLEXYX
FROM
(
SELECT A.FID
FROM View_Table_Temp2 A
JOIN View_Table_Temp3 B
ON A.FCONTRACTNUMBER = B.FCONTRACTNUMBER
AND A.FCREATEDATE = B.FCREATEDATE
UNION ALL
SELECT *
FROM View_Table_Temp1
) W;
SELECT A.FBILLNO AS 'AFBILLNO',
A.F_ORDERTYPE,
CONVERT(NVARCHAR, A.FDATE, 23) AS 'Date', --日期
MONTH(A.FDATE) AS 'Month', --月份
E.FNAME AS 'Client', --购货单位
F.FNAME AS 'Currency', --币别
ISNULL(E.FDATAVALUE, '') AS 'CreditType', --客户信用类型
A.F_CONTRACTNUMBER AS 'ContractNumber', --纸质合同号
ISNULL(G.FSPECIFICATION, '') AS 'SizeModel', --规格型号
B.FQTY - ISNULL(B3.FRETNOTICEQTY, 0) AS 'Quantity', --数量
B2.FTAXPRICE AS 'TaxPrice', --实际含税单价
B2.FALLAMOUNT_LC - ISNULL(ABS(B3.FALLAMOUNT_LC), 0) AS 'AllAmount', --价税合计
ISNULL(H.FNAME, '') AS 'ProjectName', --项目名称
ISNULL(H2.FNAME, '') AS 'SalerName', --业务员
ISNULL(H3.FNAME, '') AS 'SaleDeptName', --部门
ISNULL(H4.FNAME, '') AS 'Supervisor', --审批人
H5.FDATAVALUE AS 'SpecialCauseType', --特价原因分类
A.FCRMSPECIALPRICINGREASON AS 'CRMSpecialCause', --CRM特价原因
CASE
WHEN A.F_ORDERTYPE = 'YB' THEN
B.F_SETTLEMENTP
ELSE
NULL
END AS 'CurrentSettledUpset1', --当期结算价(仪表)
CASE
WHEN A.F_ORDERTYPE = 'XT'
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
ELSE
NULL
END AS 'CurrentSettledUpset2', --当期结算价(系统)
(B2.FTAXPRICE - B.F_SETTLEMENTP) AS 'Difference', --差额(单价-底价)
--P、C、E、S
CASE
WHEN
(
D.FNUMBER = 'P'
OR D.FNUMBER = 'C'
OR D.FNUMBER = 'E'
OR D.FNUMBER = 'S'
) THEN
((B2.FTAXPRICE - B.F_SETTLEMENTP) * B.FQTY) --(仪表)
--ES、W、SX、D、CY
WHEN (
D.FNUMBER = 'ES'
OR D.FNUMBER = 'W'
OR D.FNUMBER = 'SX'
OR D.FNUMBER = 'D'
OR D.FNUMBER = 'CY'
)
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
--CS、CW
WHEN (
D.FNUMBER = 'CS'
OR D.FNUMBER = 'CW'
)
AND A.FSALEORGID = 100303 THEN
((B2.FTAXPRICE - B.F_SETTLEMENTP) * B.FQTY)
WHEN (
D.FNUMBER = 'CS'
OR D.FNUMBER = 'CW'
)
AND A.FSALEORGID != 100303
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
ELSE
NULL
END AS 'TotalSpread', --总价差(终)
C2.FNAME + ',' + TRY_CAST(FLOOR(C2.F_DAY) AS NVARCHAR(MAX)) + '天,'
+ TRY_CAST(FLOOR(C2.FRECADVANCERATE) AS NVARCHAR(MAX)) + '%' AS 'PaymentMethods', --付款方式
CASE
WHEN A.F_ORDERTYPE = 'YB' THEN
'仪表合同' --(仪表)
WHEN A.F_ORDERTYPE = 'XT' THEN --(系统)
(CASE
WHEN ISNULL(A.F_XMYSSJ, '') != '' THEN
CONVERT(NVARCHAR, A.F_XMYSSJ, 23)
WHEN C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0) <= 0 THEN
'发货完成'
WHEN C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0) = C.FBILLALLAMOUNT_LC
- ISNULL(
ABS(B3.FBillAllAmount_LC),
0
) THEN
'未发货'
ELSE
'部分发货'
END
)
ELSE
''
END AS 'ProjectPhase', --项目阶段
CASE
WHEN ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0)
ELSE
NULL
END AS 'OrderAllAmount', --订单总额
CASE
WHEN ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0)
ELSE
NULL
END AS 'NotShipmentsAmount', --未发货金额
CASE
WHEN CONVERT(NVARCHAR(10), DATEADD(DAY, ISNULL(C2.F_DAY, 0), C2.F_PMSDATE), 23) > GETDATE()
AND C2.FRECADVANCEAMOUNT > C2.FRECAMOUNT
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C2.FRECADVANCEAMOUNT - C2.FRECAMOUNT
ELSE
NULL
END AS 'ExpireUnpaidAmount', --到期未付金额
G.FNUMBER AS 'ProductsCode' --产品长代码
INTO #TempTable1
FROM T_SAL_ORDERENTRY B --销售订单明细表
JOIN T_SAL_ORDER A --销售订单表
ON A.FID = B.FID
LEFT JOIN T_SAL_ORDERENTRY_F B2 --销售订单明细_F表
ON B.FENTRYID = B2.FENTRYID
LEFT JOIN
(
SELECT Aq2.FBillAllAmount_LC,
Aq.*
FROM
(
SELECT W2.FSID,
W2.FSBILLID,
STRING_AGG(CONVERT(NVARCHAR, W1.FDATE, 23), ',') AS 'FDate',
SUM(W1.FPRICEUNITQTY) AS 'FRETNOTICEQTY',
SUM(W1.FALLAMOUNT_LC) AS 'FALLAMOUNT_LC'
FROM
(
SELECT q1.FDATE,
q3.FSID,
q2.FALLAMOUNT_LC,
q2.FPRICEUNITQTY
FROM T_SAL_RETURNNOTICE q1
JOIN T_SAL_RETURNNOTICEENTRY_F q2
ON q1.FID = q2.FID
JOIN T_SAL_RETURNNOTICEENTRY_LK q3
ON q2.FENTRYID = q3.FENTRYID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
AND q3.FSTABLENAME = 'T_SAL_ORDERENTRY'
) W1
JOIN T_SAL_ORDERENTRY_LK W2
ON W1.FSID = W2.FENTRYID
GROUP BY W2.FSID,
W2.FSBILLID
) Aq
JOIN
(
SELECT W2.FSBILLID,
STRING_AGG(CONVERT(NVARCHAR, W1.FDATE, 23), ',') AS 'FDate',
SUM(W1.FPRICEUNITQTY) AS 'FRETNOTICEQTY',
SUM(W1.FALLAMOUNT_LC) AS 'FBillAllAmount_LC'
FROM
(
SELECT q1.FDATE,
q3.FSID,
q2.FALLAMOUNT_LC,
q2.FPRICEUNITQTY
FROM T_SAL_RETURNNOTICE q1
JOIN T_SAL_RETURNNOTICEENTRY_F q2
ON q1.FID = q2.FID
JOIN T_SAL_RETURNNOTICEENTRY_LK q3
ON q2.FENTRYID = q3.FENTRYID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
AND q3.FSTABLENAME = 'T_SAL_ORDERENTRY'
) W1
JOIN T_SAL_ORDERENTRY_LK W2
ON W1.FSID = W2.FENTRYID
GROUP BY W2.FSBILLID
) Aq2
ON Aq.FSBILLID = Aq2.FSBILLID
) B3 --销售订单-表关联表(销售退货)
ON B.FENTRYID = B3.FSID
JOIN T_SAL_ORDERFIN C --销售订单_财务表
ON A.FID = C.FID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_SAL_ORDERPLAN q1
JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BD_RECCONDITION q1
LEFT JOIN T_BD_RECCONDITION_L q2
ON q1.FID = q2.FID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) q2
ON q1.F_RECCONDITIONID = q2.FID
) C2 --销售订单_收款计划
ON A.FID = C2.FID
LEFT JOIN
(
SELECT FNUMBER,
FMASTERID
FROM T_BAS_ASSISTANTDATAENTRY
WHERE FID = '670cc977263353'
AND FDOCUMENTSTATUS = 'C'
AND FFORBIDSTATUS = 'A'
) D --合同类型#(辅助资料表)
ON A.F_ORDERCATEGORY = D.FMASTERID
LEFT JOIN
(
SELECT A2.FDATAVALUE,
A1.*
FROM
(
SELECT q2.FNAME,
q1.*
FROM T_BD_CUSTOMER q1
JOIN T_BD_CUSTOMER_L q2
ON q1.FCUSTID = q2.FCUSTID
) A1
LEFT JOIN
(
SELECT A.FMASTERID,
B.FDATAVALUE
FROM T_BAS_ASSISTANTDATAENTRY A
JOIN T_BAS_ASSISTANTDATAENTRY_L B
ON A.FENTRYID = B.FENTRYID
WHERE A.FID = '673af6092e2877'
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) A2
ON A1.F_CREDITCLASSIFICATION = A2.FMASTERID
) E --客户_L表
ON A.FCUSTID = E.FCUSTID
LEFT JOIN
(SELECT * FROM T_BD_CURRENCY_L WHERE FLOCALEID = 2052) F --币别表
ON C.FSETTLECURRID = F.FCURRENCYID
LEFT JOIN
(
SELECT B.FNAME,
B.FSPECIFICATION,
A.*
FROM T_BD_MATERIAL A
JOIN T_BD_MATERIAL_L B
ON A.FMATERIALID = B.FMATERIALID
WHERE B.FLOCALEID = 2052
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) G --物料表
ON G.FMATERIALID = B.FMATERIALID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BAS_PREBDONE q1
JOIN T_BAS_PREBDONE_L q2
ON q1.FID = q2.FID
WHERE q2.FLocaleID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H --工程项目表预置基础资料1
ON H.FID = A.F_PROJECTNAME
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM V_BD_SALESMAN q1
LEFT JOIN V_BD_SALESMAN_L q2
ON q1.fid = q2.fid
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
AND q1.FFORBIDDENSTATUS = '0'
) H2 --销售员表
ON A.FSALERID = H2.fid
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BD_DEPARTMENT q1
JOIN T_BD_DEPARTMENT_L q2
ON q1.FDEPTID = q2.FDEPTID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H3 --销售部门表
ON A.FSALEDEPTID = H3.FDEPTID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_HR_EMPINFO q1
JOIN T_HR_EMPINFO_L q2
ON q1.FID = q2.FID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H4 --主管#(员工表)
ON A.F_VRYF_BASE_FG2 = H4.FID
LEFT JOIN
(
SELECT A.FNUMBER,
A.FMASTERID,
B.FDATAVALUE
FROM T_BAS_ASSISTANTDATAENTRY A
JOIN T_BAS_ASSISTANTDATAENTRY_L B
ON A.FENTRYID = B.FENTRYID
WHERE A.FID = '674f073de0bc25'
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) H5
ON H5.FMASTERID = A.FSPECIALRESON
LEFT JOIN
(
SELECT W2.FSID,
SUM(W1.FALLAMOUNT_LC) AS 'FALLAMOUNT_LC'
FROM
(
SELECT q2.FALLAMOUNT_LC,
q2.FENTRYID
FROM T_SAL_DELIVERYNOTICE q1
JOIN T_SAL_DELIVERYNOTICEENTRY_F q2
ON q1.FID = q2.FID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
) W1
JOIN T_SAL_DELIVERYNOTICEENTRY_LK W2
ON W1.FENTRYID = W2.FENTRYID
WHERE W2.FSTABLENAME = 'T_SAL_ORDERENTRY'
GROUP BY W2.FSID
) H6 --发货通知单表
ON B.FENTRYID = H6.FSID
LEFT JOIN
(
SELECT W2.FSID,
W1.*
FROM
(
SELECT B.FALLAMOUNTFOR,
B.FENTRYID
FROM T_AR_RECEIVABLE A
JOIN T_AR_RECEIVABLEENTRY B
ON A.FID = B.FID
WHERE A.FDOCUMENTSTATUS = 'C'
AND B.FORDERNUMBER != ''
AND A.FENDDATE <= GETDATE()
) W1
JOIN T_AR_RECEIVABLEENTRY_LK W2
ON W1.FENTRYID = W2.FENTRYID
WHERE W2.FSTABLENAME = 'T_SAL_ORDERENTRY'
) H7
ON B.FENTRYID = H7.FSID
WHERE D.FNUMBER IN ( 'P', 'E', 'C', 'S' )
AND B.F_SPECIALOFFER = '1'
AND B.F_YKQC_CHECKBOX_QTR != '1'
AND A.FDOCUMENTSTATUS = 'C'
AND A.FBUSINESSTYPE = 'NORMAL'
AND B.FQTY >= 0
AND A.FMANUALCLOSE = '0'
AND A.FID IN
(
SELECT * FROM #TABLEXYX
)
AND A.FMANUALCLOSE <> '1'
AND B.FMANUALROWCLOSE <> '1'
AND A.F_CONTRACTNUMBER NOT LIKE 'Z%'
AND A.FID NOT IN
(
SELECT FID FROM #TEMP3
)
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') >= '2025-06-01 00:00:00'
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') <= '2025-06-20 00:00:00';
--1.1.确定单价总额<结算总价的,判断为特价合同,取整单明细;
--1.2.所有订单无论是否有特价的,需要财务审批为特价的,取整单明细;
/*dialect*/
SELECT A.FBILLNO AS 'AFBILLNO',
A.F_ORDERTYPE,
CONVERT(NVARCHAR, A.FAPPROVEDATE, 23) AS 'Date', --日期
MONTH(A.FAPPROVEDATE) AS 'Month', --月份
E.FNAME AS 'Client', --购货单位
F.FNAME AS 'Currency', --币别
ISNULL(E.FDATAVALUE, '') AS 'CreditType', --客户信用类型
A.F_CONTRACTNUMBER AS 'ContractNumber', --纸质合同号
ISNULL(G.FSPECIFICATION, '') AS 'SizeModel', --规格型号
B.FQTY - ISNULL(B3.FRETNOTICEQTY, 0) AS 'Quantity', --数量
B2.FTAXPRICE AS 'TaxPrice', --实际含税单价
B2.FALLAMOUNT_LC - ISNULL(ABS(B3.FAllAmount_LC), 0) AS 'AllAmount', --价税合计
ISNULL(H.FNAME, '') AS 'ProjectName', --项目名称
ISNULL(H2.FNAME, '') AS 'SalerName', --业务员
ISNULL(H3.FNAME, '') AS 'SaleDeptName', --部门
ISNULL(H4.FNAME, '') AS 'Supervisor', --审批人
H5.FDATAVALUE AS 'SpecialCauseType', --特价原因分类
A.FCRMSPECIALPRICINGREASON AS 'CRMSpecialCause', --CRM特价原因
CASE
WHEN A.F_ORDERTYPE = 'YB' THEN
B.F_SETTLEMENTP
ELSE
NULL
END AS 'CurrentSettledUpset1', --当期结算价(仪表)
CASE
WHEN A.F_ORDERTYPE = 'XT'
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
ELSE
NULL
END AS 'CurrentSettledUpset2', --当期结算价(系统)
(B2.FTAXPRICE - B.F_SETTLEMENTP) AS 'Difference', --差额(单价-底价)
--P、C、E、S
CASE
WHEN
(
D.FNUMBER = 'P'
OR D.FNUMBER = 'C'
OR D.FNUMBER = 'E'
OR D.FNUMBER = 'S'
) THEN
((B2.FTAXPRICE - B.F_SETTLEMENTP) * B.FQTY) --(仪表)
--ES、W、SX、D、CY
WHEN (
D.FNUMBER = 'ES'
OR D.FNUMBER = 'W'
OR D.FNUMBER = 'SX'
OR D.FNUMBER = 'D'
OR D.FNUMBER = 'CY'
)
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
--CS、CW
WHEN (
D.FNUMBER = 'CS'
OR D.FNUMBER = 'CW'
)
AND A.FSALEORGID = 100303 THEN
((B2.FTAXPRICE - B.F_SETTLEMENTP) * B.FQTY)
WHEN (
D.FNUMBER = 'CS'
OR D.FNUMBER = 'CW'
)
AND A.FSALEORGID != 100303
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - CAST(ISNULL(A.F_YKQC_TEXT_QTR, 0) AS FLOAT)
ELSE
NULL
END AS 'TotalSpread', --总价差(终)
C2.FNAME + ',' + TRY_CAST(FLOOR(C2.F_DAY) AS NVARCHAR(MAX)) + '天,'
+ TRY_CAST(FLOOR(C2.FRECADVANCERATE) AS NVARCHAR(MAX)) + '%' AS 'PaymentMethods', --付款方式
CASE
WHEN A.F_ORDERTYPE = 'YB' THEN
'仪表合同' --(仪表)
WHEN A.F_ORDERTYPE = 'XT' THEN --(系统)
(CASE
WHEN ISNULL(A.F_XMYSSJ, '') != '' THEN
CONVERT(NVARCHAR, A.F_XMYSSJ, 23)
WHEN C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0) <= 0 THEN
'发货完成'
WHEN C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0) = C.FBILLALLAMOUNT_LC
- ISNULL(
ABS(B3.FBillAllAmount_LC),
0
) THEN
'未发货'
ELSE
'部分发货'
END
)
ELSE
''
END AS 'ProjectPhase', --项目阶段
CASE
WHEN ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0)
ELSE
NULL
END AS 'OrderAllAmount', --订单总额
CASE
WHEN ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C.FBILLALLAMOUNT_LC - ISNULL(ABS(B3.FBillAllAmount_LC), 0) - ISNULL(H6.FALLAMOUNT_LC, 0)
ELSE
NULL
END AS 'NotShipmentsAmount', --未发货金额
CASE
WHEN CONVERT(NVARCHAR(10), DATEADD(DAY, ISNULL(C2.F_DAY, 0), C2.F_PMSDATE), 23) > GETDATE()
AND C2.FRECADVANCEAMOUNT > C2.FRECAMOUNT
AND ROW_NUMBER() OVER (PARTITION BY A.F_CONTRACTNUMBER ORDER BY B.FSEQ) = 1 THEN
C2.FRECADVANCEAMOUNT - C2.FRECAMOUNT
ELSE
NULL
END AS 'ExpireUnpaidAmount', --到期未付金额
G.FNUMBER AS 'ProductsCode' --产品长代码
INTO #TempTable2
FROM T_SAL_ORDERENTRY B --销售订单明细表
JOIN T_SAL_ORDER A --销售订单表
ON A.FID = B.FID
LEFT JOIN T_SAL_ORDERENTRY_F B2 --销售订单明细_F表
ON B.FENTRYID = B2.FENTRYID
LEFT JOIN
(
SELECT Aq2.FBillAllAmount_LC,
Aq.*
FROM
(
SELECT W2.FSID,
W2.FSBILLID,
STRING_AGG(CONVERT(NVARCHAR, W1.FDATE, 23), ',') AS 'FDate',
SUM(W1.FPRICEUNITQTY) AS 'FRETNOTICEQTY',
SUM(W1.FALLAMOUNT_LC) AS 'FAllAmount_LC'
FROM
(
SELECT q1.FDATE,
q3.FSID,
q2.FALLAMOUNT_LC,
q2.FPRICEUNITQTY
FROM T_SAL_RETURNNOTICE q1
JOIN T_SAL_RETURNNOTICEENTRY_F q2
ON q1.FID = q2.FID
JOIN T_SAL_RETURNNOTICEENTRY_LK q3
ON q2.FENTRYID = q3.FENTRYID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
AND q3.FSTABLENAME = 'T_SAL_ORDERENTRY'
) W1
JOIN T_SAL_ORDERENTRY_LK W2
ON W1.FSID = W2.FENTRYID
GROUP BY W2.FSID,
W2.FSBILLID
) Aq
JOIN
(
SELECT W2.FSBILLID,
STRING_AGG(CONVERT(NVARCHAR, W1.FDATE, 23), ',') AS 'FDate',
SUM(W1.FPRICEUNITQTY) AS 'FRETNOTICEQTY',
SUM(W1.FALLAMOUNT_LC) AS 'FBillAllAmount_LC'
FROM
(
SELECT q1.FDATE,
q3.FSID,
q2.FALLAMOUNT_LC,
q2.FPRICEUNITQTY
FROM T_SAL_RETURNNOTICE q1
JOIN T_SAL_RETURNNOTICEENTRY_F q2
ON q1.FID = q2.FID
JOIN T_SAL_RETURNNOTICEENTRY_LK q3
ON q2.FENTRYID = q3.FENTRYID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
AND q3.FSTABLENAME = 'T_SAL_ORDERENTRY'
) W1
JOIN T_SAL_ORDERENTRY_LK W2
ON W1.FSID = W2.FENTRYID
GROUP BY W2.FSBILLID
) Aq2
ON Aq.FSBILLID = Aq2.FSBILLID
) B3 --销售订单-表关联表
ON B.FENTRYID = B3.FSID
JOIN T_SAL_ORDERFIN C --销售订单_财务表
ON A.FID = C.FID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_SAL_ORDERPLAN q1
JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BD_RECCONDITION q1
LEFT JOIN T_BD_RECCONDITION_L q2
ON q1.FID = q2.FID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) q2
ON q1.F_RECCONDITIONID = q2.FID
) C2 --销售订单_收款计划
ON A.FID = C2.FID
LEFT JOIN
(
SELECT FNUMBER,
FMASTERID
FROM T_BAS_ASSISTANTDATAENTRY
WHERE FID = '670cc977263353'
AND FDOCUMENTSTATUS = 'C'
AND FFORBIDSTATUS = 'A'
) D --合同类型#(辅助资料表)
ON A.F_ORDERCATEGORY = D.FMASTERID
LEFT JOIN
(
SELECT A2.FDATAVALUE,
A1.*
FROM
(
SELECT q2.FNAME,
q1.*
FROM T_BD_CUSTOMER q1
JOIN T_BD_CUSTOMER_L q2
ON q1.FCUSTID = q2.FCUSTID
) A1
LEFT JOIN
(
SELECT A.FMASTERID,
B.FDATAVALUE
FROM T_BAS_ASSISTANTDATAENTRY A
JOIN T_BAS_ASSISTANTDATAENTRY_L B
ON A.FENTRYID = B.FENTRYID
WHERE A.FID = '673af6092e2877'
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) A2
ON A1.F_CREDITCLASSIFICATION = A2.FMASTERID
) E --客户_L表
ON A.FCUSTID = E.FCUSTID
LEFT JOIN
(SELECT * FROM T_BD_CURRENCY_L WHERE FLOCALEID = 2052) F --币别表
ON C.FSETTLECURRID = F.FCURRENCYID
LEFT JOIN
(
SELECT B.FNAME,
B.FSPECIFICATION,
A.*
FROM T_BD_MATERIAL A
JOIN T_BD_MATERIAL_L B
ON A.FMATERIALID = B.FMATERIALID
WHERE B.FLOCALEID = 2052
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) G --物料表
ON G.FMATERIALID = B.FMATERIALID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BAS_PREBDONE q1
JOIN T_BAS_PREBDONE_L q2
ON q1.FID = q2.FID
WHERE q2.FLocaleID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H --工程项目表预置基础资料1
ON H.FID = A.F_PROJECTNAME
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM V_BD_SALESMAN q1
LEFT JOIN V_BD_SALESMAN_L q2
ON q1.fid = q2.fid
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
AND q1.FFORBIDDENSTATUS = '0'
) H2 --销售员表
ON A.FSALERID = H2.fid
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_BD_DEPARTMENT q1
JOIN T_BD_DEPARTMENT_L q2
ON q1.FDEPTID = q2.FDEPTID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H3 --销售部门表
ON A.FSALEDEPTID = H3.FDEPTID
LEFT JOIN
(
SELECT q2.FNAME,
q1.*
FROM T_HR_EMPINFO q1
JOIN T_HR_EMPINFO_L q2
ON q1.FID = q2.FID
WHERE q2.FLOCALEID = 2052
AND q1.FDOCUMENTSTATUS = 'C'
AND q1.FFORBIDSTATUS = 'A'
) H4 --主管#(员工表)
ON A.F_VRYF_BASE_FG2 = H4.FID
LEFT JOIN
(
SELECT A.FNUMBER,
A.FMASTERID,
B.FDATAVALUE
FROM T_BAS_ASSISTANTDATAENTRY A
JOIN T_BAS_ASSISTANTDATAENTRY_L B
ON A.FENTRYID = B.FENTRYID
WHERE A.FID = '674f073de0bc25'
AND A.FDOCUMENTSTATUS = 'C'
AND A.FFORBIDSTATUS = 'A'
) H5
ON H5.FMASTERID = A.FSPECIALRESON
LEFT JOIN
(
SELECT W2.FSID,
SUM(W1.FALLAMOUNT_LC) AS 'FALLAMOUNT_LC'
FROM
(
SELECT q2.FALLAMOUNT_LC,
q2.FENTRYID
FROM T_SAL_DELIVERYNOTICE q1
JOIN T_SAL_DELIVERYNOTICEENTRY_F q2
ON q1.FID = q2.FID
WHERE q1.FDOCUMENTSTATUS = 'C'
AND q1.FCANCELSTATUS = 'A'
) W1
JOIN T_SAL_DELIVERYNOTICEENTRY_LK W2
ON W1.FENTRYID = W2.FENTRYID
WHERE W2.FSTABLENAME = 'T_SAL_ORDERENTRY'
GROUP BY W2.FSID
) H6
ON B.FENTRYID = H6.FSID
LEFT JOIN
(
SELECT W2.FSID,
W1.*
FROM
(
SELECT B.FALLAMOUNTFOR,
B.FENTRYID
FROM T_AR_RECEIVABLE A
JOIN T_AR_RECEIVABLEENTRY B
ON A.FID = B.FID
WHERE A.FDOCUMENTSTATUS = 'C'
AND B.FORDERNUMBER != ''
AND A.FENDDATE <= GETDATE()
) W1
JOIN T_AR_RECEIVABLEENTRY_LK W2
ON W1.FENTRYID = W2.FENTRYID
WHERE W2.FSTABLENAME = 'T_SAL_ORDERENTRY'
) H7 --收款单
ON B.FENTRYID = H7.FSID
--ES、W、SX、CW、D、CY
WHERE D.FNUMBER NOT IN ( 'P', 'E', 'C', 'S' )
AND (A.F_YKQC_CHECKBOX_QTR1 = 1 OR a.F_GROSSMARGIN1='<35%')
AND B.FQTY >= 0
AND A.FDOCUMENTSTATUS = 'C'
AND A.FBUSINESSTYPE = 'NORMAL'
AND A.FMANUALCLOSE = '0'
AND A.FID IN
(
SELECT * FROM #TABLEXYX
)
AND A.F_CONTRACTNUMBER NOT LIKE 'Z%'
AND A.FMANUALCLOSE <> '1'
AND B.FMANUALROWCLOSE <> '1'
AND A.FID NOT IN
(
SELECT FID FROM #TEMP3
)
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') >= '2025-06-01 00:00:00'
AND FORMAT(A.FAPPROVEDATE, 'yyyy-MM-dd') <= '2025-06-20 00:00:00';
--仪表P、C、E、S明细单价<结算单价,则判断为特价合同,取明细金额;
/*dialect*/
SELECT *
INTO #TempTable3
FROM #TempTable1
UNION ALL
SELECT *
FROM #TempTable2;
SELECT *
INTO #TempTable4
FROM #TempTable3
WHERE 1 = 1;
/*dialect*/
SELECT *,
ROW_NUMBER() OVER (ORDER BY ContractNumber, t1.Sort DESC) AS FID,
ROW_NUMBER() OVER (ORDER BY ContractNumber, t1.Sort DESC) AS FIDENTITYID
INTO TMP5CAD9BB84D8011F0AD6E90F6533
FROM
(
SELECT *,
1 Sort
FROM #TempTable4
--UNION ALL
--SELECT
--'',
--'',
--'合计:',
--null,
--'',
--'',
--'',
--'',
--'',
--SUM(t1.Quantity),--数量
--SUM(t1.TaxPrice),
--SUM(t1.AllAmount),
--'',
--'',
--'',
--'',
--'',
--'',
--SUM(t1.CurrentSettledUpset1),
--SUM(t1.CurrentSettledUpset2),
--SUM(t1.Difference),
--SUM(t1.TotalSpread),
--'',
--'',
--SUM(t1.OrderAllAmount),
--SUM(t1.NotShipmentsAmount),
--SUM(t1.ExpireUnpaidAmount),
--'',
--0 Sort
--FROM #TempTable4 t1
) t1
ORDER BY Sort DESC;
--SELECT * FROM TMP5CAD9BB84D8011F0AD6E90F6533