104 lines
3.8 KiB
SQL
104 lines
3.8 KiB
SQL
;WITH #销售合同计算 AS (
|
|
SELECT
|
|
t0.FID,t0.FBILLNO
|
|
,t0.FNAME as FName
|
|
,t0.FDOCUMENTSTATUS
|
|
,t0.F_CYG_ContractNoDL
|
|
,'A' AS 'FFORBIDSTATUS'
|
|
,t0f.FCONTRACTAMOUNT_LC AS 'FCONTRACTAMOUNT'
|
|
,ISNULL(t4.FCONTRACTAMOUNT_X,0) AS 'FCONTRACTAMOUNT_X'
|
|
,ISNULL(t1.SAL_ORDER_AMOUNT,0) AS 'SAL_ORDER_AMOUNT'
|
|
,ISNULL(t1.公开价小计,0) AS '公开价小计'
|
|
,ISNULL(t1.外购价小计,0) AS '外购价小计'
|
|
,ISNULL(t1.安装费小计,0) AS '安装费小计'
|
|
,ISNULL(t1.成本小计,0) AS '成本小计'
|
|
,ISNULL(t2.AR_RECEIVABLE_AMOUNT,0) AS 'AR_RECEIVABLE_AMOUNT'
|
|
,ISNULL(t3.AR_RECEIVABLE_AMOUNT2,0) AS 'AR_RECEIVABLE_AMOUNT2'
|
|
--,ISNULL(t3.FIVALLAMOUNTFOR,0) AS 'FIVALLAMOUNTFOR'
|
|
FROM T_CRM_CONTRACT t0
|
|
INNER JOIN T_CRM_CONTRACTFIN t0f on t0f.FID = t0.FID
|
|
OUTER APPLY (
|
|
SELECT t0.FID AS 'CONTRACT_ID'
|
|
,SUM(t1e_f.FALLAMOUNT_LC) SAL_ORDER_AMOUNT
|
|
,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 t1.FCRMContractId = t0.FID
|
|
AND t1.FDOCUMENTSTATUS = 'C'
|
|
GROUP BY t1.FCRMContractId
|
|
) t1
|
|
OUTER APPLY (
|
|
SELECT SUM(t3e.FALLAMOUNT) AS AR_RECEIVABLE_AMOUNT,tt.FCRMContractId
|
|
--,SUM(t3e.FALLAMOUNTFOR) AS 'FALLAMOUNTFOR'
|
|
FROM T_SAL_ORDER tt
|
|
INNER JOIN T_AR_RECEIVABLE t3 on tt.FBILLNO = t3.FBILLNOS
|
|
INNER JOIN T_AR_RECEIVABLEENTRY t3e on t3e.FID = t3.FID
|
|
WHERE tt.FCRMContractId = t0.FID
|
|
AND tt.FDOCUMENTSTATUS = 'C'
|
|
AND t3.FSETACCOUNTTYPE = '2'--立账类型:暂估
|
|
AND t3.FDOCUMENTSTATUS = 'C'
|
|
AND CHARINDEX('-',t3.FBILLNO) = 0
|
|
GROUP BY tt.FCRMContractId
|
|
) t2
|
|
OUTER APPLY (
|
|
SELECT SUM(t3e.FALLAMOUNT) AS AR_RECEIVABLE_AMOUNT2,tt.FCRMContractId
|
|
--,SUM(t3e.FALLAMOUNTFOR) AS 'FALLAMOUNTFOR'
|
|
FROM T_SAL_ORDER tt
|
|
INNER JOIN T_AR_RECEIVABLE t3 on tt.FBILLNO = t3.FBILLNOS
|
|
INNER JOIN T_AR_RECEIVABLEENTRY t3e on t3e.FID = t3.FID
|
|
WHERE tt.FCRMContractId = t0.FID
|
|
AND tt.FDOCUMENTSTATUS = 'C'
|
|
AND t3.FSETACCOUNTTYPE = '3'--立账类型:财务
|
|
AND t3.FDOCUMENTSTATUS = 'C'
|
|
AND CHARINDEX('-',t3.FBILLNO) = 0
|
|
GROUP BY tt.FCRMContractId
|
|
) t3
|
|
OUTER APPLY (
|
|
SELECT TOP 1 t4f.FCONTRACTAMOUNT_LC AS 'FCONTRACTAMOUNT_X'
|
|
FROM T_CRM_XCONTRACT t4
|
|
INNER JOIN T_CRM_XCONTRACTFIN t4f on t4.FID = t4f.FID
|
|
WHERE t4.FPKIDX = t0.FID
|
|
ORDER BY t4.FID DESC
|
|
) t4
|
|
WHERE 1=1
|
|
AND t0.FDOCUMENTSTATUS = 'C'
|
|
)
|
|
, #最终数据 AS (
|
|
SELECT t0.FID,t0.FBILLNO
|
|
,t0.FCONTRACTAMOUNT AS '合同金额'
|
|
,t0.FCONTRACTAMOUNT_X AS '合同变化金额'
|
|
,t0.SAL_ORDER_AMOUNT AS '累计销售订单本位币'
|
|
,t0.FCONTRACTAMOUNT - t0.SAL_ORDER_AMOUNT AS '未下单销售订单本位币'
|
|
,t0.AR_RECEIVABLE_AMOUNT AS '累计发货本位币'
|
|
,t0.SAL_ORDER_AMOUNT - t0.AR_RECEIVABLE_AMOUNT AS '剩余未发货本位币'
|
|
,0 AS '合同收款金额'
|
|
,0 AS '合同发货未收款金额'
|
|
,t0.AR_RECEIVABLE_AMOUNT2 AS '累计开票金额'
|
|
,t0.AR_RECEIVABLE_AMOUNT - t0.AR_RECEIVABLE_AMOUNT2 AS '未开票金额'
|
|
,t0.公开价小计
|
|
,t0.外购价小计
|
|
,t0.安装费小计
|
|
,t0.成本小计
|
|
FROM #销售合同计算 t0
|
|
)
|
|
--SELECT * FROM #最终数据 t0
|
|
--WHERE t0.FBILLNO = 'XSHT106734'
|
|
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 |