129 lines
4.7 KiB
SQL
129 lines
4.7 KiB
SQL
;WITH #销售订单 AS (
|
|
SELECT t1.FSALES
|
|
,SUM(t1e_f.FALLAMOUNT_LC) '累计销售订单本位币'
|
|
,SUM(t1e.F_CYG_OPENTOTAL) AS '公开价小计'
|
|
,SUM(t1e.F_CYG_OUTSOURCINGTOTAL) AS '外购价小计'
|
|
,SUM(t1e.F_CYG_MOUNTINGTOTAL) AS '安装费小计'
|
|
,SUM(t1e.F_CYG_COSTTOTAL) AS '成本小计'
|
|
FROM T_SAL_ORDER t1
|
|
INNER JOIN T_SAL_ORDERENTRY t1e on t1e.FID = t1.FID
|
|
INNER JOIN T_SAL_ORDERENTRY_F t1e_f on t1e_f.FENTRYID = t1e.FENTRYID
|
|
WHERE 1=1
|
|
AND t1.FDOCUMENTSTATUS = 'C'
|
|
AND t1.F_CYG_CHECKBALANCE != '1'
|
|
AND t1e.F_CYG_CHECKBALANCE1 != '1'
|
|
AND t1.FBILLTYPEID != 'a300e2620037435492aed9842875b451'
|
|
AND t1e.FMRPTERMINATESTATUS != 'B'
|
|
GROUP BY t1.FSALES
|
|
)
|
|
SELECT t1.*
|
|
,t2.累计发货本位币
|
|
,t3.累计开票金额
|
|
INTO #销售订单计算
|
|
FROM #销售订单 t1
|
|
OUTER APPLY (
|
|
SELECT SUM(t3e.FALLAMOUNT) AS '累计发货本位币'
|
|
FROM T_AR_RECEIVABLE t3
|
|
INNER JOIN T_AR_RECEIVABLEENTRY t3e on t3e.FID = t3.FID
|
|
WHERE t1.FSALES = t3.FSALES
|
|
AND t3.FSETACCOUNTTYPE = '2'--立账类型:暂估
|
|
AND t3.FDOCUMENTSTATUS = 'C'
|
|
AND t3.FBYVERIFY = '0'
|
|
GROUP BY t3.FSALES
|
|
) t2
|
|
OUTER APPLY (
|
|
SELECT SUM(t3e.FALLAMOUNT) AS '累计开票金额'
|
|
FROM T_AR_RECEIVABLE t3
|
|
INNER JOIN T_AR_RECEIVABLEENTRY t3e on t3e.FID = t3.FID
|
|
WHERE t1.FSALES = t3.FSALES
|
|
AND t3.FSETACCOUNTTYPE = '3'--立账类型:财务
|
|
AND t3.FDOCUMENTSTATUS = 'C'
|
|
AND CHARINDEX('-',t3.FBILLNO) = 0
|
|
GROUP BY t3.FSALES
|
|
) t3
|
|
|
|
;WITH #合同变更 AS (
|
|
SELECT t4.FOldFId
|
|
,CAST(t4.FJSONDATA AS nvarchar(4000)) AS 'FJSONDATA'
|
|
,ROW_NUMBER() OVER (PARTITION BY t4.FOldFId ORDER BY t4.FVERSION DESC) RN
|
|
FROM T_SCM_BILLCHANGEVERSIONS t4
|
|
WHERE 1 = 1
|
|
AND t4.FFormId = 'CRM_Contract'
|
|
AND t4.FACTIVESTATUS != 'A'
|
|
)
|
|
,#销售合同计算 AS (
|
|
SELECT t0.FID,t0.FBILLNO,t0.F_CYG_SALESNUMBER
|
|
,t0.FNAME as FName
|
|
,t0.FDOCUMENTSTATUS
|
|
,t0.F_CYG_ContractNoDL
|
|
,'A' AS 'FFORBIDSTATUS'
|
|
,t0f.FCONTRACTAMOUNT_LC AS '合同金额'
|
|
,ISNULL(t4.FCONTRACTAMOUNT_X,t0f.F_CYG_CONTRACTCHANGE) AS '合同变化金额'
|
|
,ISNULL(t1.累计销售订单本位币,0) AS '累计销售订单本位币'
|
|
,ISNULL(t1.公开价小计,0) AS '公开价小计'
|
|
,ISNULL(t1.外购价小计,0) AS '外购价小计'
|
|
,ISNULL(t1.安装费小计,0) AS '安装费小计'
|
|
,ISNULL(t1.成本小计,0) AS '成本小计'
|
|
,ISNULL(t1.累计发货本位币,0) AS '累计发货本位币'
|
|
,ISNULL(t1.累计开票金额,0) AS '累计开票金额'
|
|
FROM T_CRM_CONTRACT t0
|
|
INNER JOIN T_CRM_CONTRACTFIN t0f on t0f.FID = t0.FID
|
|
LEFT JOIN #销售订单计算 t1 on t1.FSALES = t0.F_CYG_YSALESNUMBER
|
|
OUTER APPLY (
|
|
SELECT CAST(JSON_VALUE(t4.FJSONDATA,'$.CRM_ContractFIN[0].FCONTRACTAMOUNT_LC') AS decimal(23,10)) - t0f.FCONTRACTAMOUNT_LC 'FCONTRACTAMOUNT_X'
|
|
FROM #合同变更 t4
|
|
WHERE t4.FOLDFID = t0.FID AND t4.RN = 2
|
|
) t4
|
|
WHERE 1=1
|
|
AND t0.FDOCUMENTSTATUS = 'C'
|
|
AND t0f.FCONTRACTAMOUNT_LC > 0
|
|
AND t0.F_CYG_CONTRACTTYPE = '664cd624468638'
|
|
AND CONVERT(int,CONVERT(varchar(4) ,t0.FDATE,112)) = 2024 --只修改这个数就可以更新对应的年份
|
|
)
|
|
SELECT tt.FID,tt.FBILLNO,tt.F_CYG_SALESNUMBER,tt.FName
|
|
--,tt.FDOCUMENTSTATUS,tt.F_CYG_CONTRACTNODL,tt.FFORBIDSTATUS
|
|
,tt.合同金额,tt.合同变化金额,tt.累计销售订单本位币,tt.合同金额 - tt.累计销售订单本位币 AS '未下单销售订单本位币'
|
|
,tt.累计发货本位币,tt.累计开票金额
|
|
,tt.累计销售订单本位币 - tt.累计发货本位币 AS '剩余未发货本位币'
|
|
,tt.累计发货本位币 - tt.累计开票金额 AS '未开票金额'
|
|
,tt.安装费小计,tt.成本小计,tt.公开价小计,tt.外购价小计
|
|
INTO #最终数据
|
|
FROM #销售合同计算 tt
|
|
INNER JOIN T_CRM_CONTRACTFIN t0 on t0.FID = tt.FID
|
|
WHERE NOT ( t0.F_CYG_CUMSALESORDERS = tt.累计销售订单本位币
|
|
AND t0.F_CYG_NOORDERSALES = tt.合同金额 - tt.累计销售订单本位币
|
|
AND t0.F_CYG_CUMSHIPMENT = tt.累计发货本位币
|
|
AND t0.F_CYG_REMAINSHIPMENT = tt.累计销售订单本位币 - tt.累计发货本位币
|
|
AND t0.F_CYG_CONTRACTCHANGE = tt.合同变化金额
|
|
AND t0.F_CYG_ACCUMULATEDINVOIC = tt.累计开票金额
|
|
AND t0.F_CYG_UNINVOICEDAMOUNT = tt.累计发货本位币 - tt.累计开票金额
|
|
AND t0.F_CYG_OPENPRICE = tt.公开价小计
|
|
AND t0.F_CYG_OUTSOURCINGPRICE = tt.外购价小计
|
|
AND t0.F_CYG_MOUNTINGCOST = tt.安装费小计
|
|
AND t0.F_CYG_COST = tt.成本小计)
|
|
|
|
UPDATE t0 SET t0.F_CYG_CUMSALESORDERS = tt.累计销售订单本位币
|
|
,t0.F_CYG_NOORDERSALES = tt.未下单销售订单本位币
|
|
,t0.F_CYG_CUMSHIPMENT = tt.累计发货本位币
|
|
,t0.F_CYG_REMAINSHIPMENT = tt.剩余未发货本位币
|
|
,t0.F_CYG_CONTRACTCOLLECTION = tt.合同收款金额
|
|
,t0.F_CYG_SHIPMENTUNCOLLECTION = tt.合同发货未收款金额
|
|
,t0.F_CYG_CONTRACTCHANGE = tt.合同变化金额
|
|
,t0.F_CYG_ACCUMULATEDINVOIC = tt.累计开票金额
|
|
,t0.F_CYG_UNINVOICEDAMOUNT = tt.未开票金额
|
|
,t0.F_CYG_OPENPRICE = tt.公开价小计
|
|
,t0.F_CYG_OUTSOURCINGPRICE = tt.外购价小计
|
|
,t0.F_CYG_MOUNTINGCOST = tt.安装费小计
|
|
,t0.F_CYG_COST = tt.成本小计
|
|
FROM T_CRM_CONTRACTFIN t0
|
|
INNER JOIN #最终数据 tt on t0.FID = tt.FID
|
|
|
|
UPDATE t0 SET t0.FDATE = GETDATE()
|
|
FROM T_CRM_CONTRACT t0
|
|
INNER JOIN #最终数据 tt on t0.FID = tt.FID
|
|
|
|
--SELECT *
|
|
--FROM #最终数据
|
|
--ORDER BY FID
|
|
DROP TABLE #销售订单计算
|
|
DROP TABLE #最终数据 |