179 lines
7.6 KiB
SQL
179 lines
7.6 KiB
SQL
SELECT
|
|
rowSet2.[1] AS 'FMATERIALID'
|
|
,CONVERT(int,rowSet2.[2]) AS 'inRow'
|
|
,rowSet2.[3] AS 'FSTOCKID'
|
|
,rowSet2.[4] AS 'FDate'
|
|
,rowSet2.[5] AS 'FSBILLID'
|
|
,rowSet2.[6] AS 'FSID'
|
|
,rowSet2.[7] AS 'FSTABLENAME'
|
|
INTO #TMP_DATA
|
|
FROM (SELECT 1 ID,CAST('<v>'+ REPLACE('140783,0,0,2024-04-07 00:00:00,0,0,',';','</v><v>') + '</v>' AS XML) AS xmlVal
|
|
) AS valSet
|
|
OUTER APPLY (
|
|
SELECT ROW_NUMBER() OVER (ORDER BY valSet.ID) RN
|
|
,CAST('<v>'+ REPLACE(T.C.value('.','varchar(100)'),',','</v><v>') + '</v>' AS XML) xmlVal
|
|
FROM valSet.xmlVal.nodes('/v') AS T(C)
|
|
) rowSet
|
|
OUTER APPLY (
|
|
SELECT TT2.* FROM (
|
|
SELECT T.C.value('.','varchar(100)') AS xmlVal
|
|
,ROW_NUMBER() OVER (ORDER BY rowSet.RN) RowNo
|
|
FROM rowSet.xmlVal.nodes('/v') AS T(C)
|
|
) TT
|
|
PIVOT (MAX(TT.xmlVal) FOR TT.RowNo IN ([1],[2],[3],[4],[5],[6],[7])) TT2
|
|
) rowSet2
|
|
|
|
/***********************************取上游单据start*****************************************/
|
|
SELECT t0e_lk.FMATERIALID
|
|
,(CASE t0e_lk.FSTABLENAME
|
|
WHEN 'T_STK_MISDELIVERYENTRY' THEN t1.FPRICE --其他出库(退货)-成本价
|
|
WHEN 'T_STK_INSTOCKENTRY' THEN t2.FPRICE --采购入库 -单价(不含税)
|
|
WHEN 'T_STK_STKTRANSFERINENTRY1' THEN t3.FPRICE --分步式调入 -参考单价
|
|
ELSE 0
|
|
END) AS 'newReferPrice'
|
|
,(CASE t0e_lk.FSTABLENAME
|
|
WHEN 'T_STK_MISDELIVERYENTRY' THEN '源_其他出库单:'+ t1.FBILLNO
|
|
WHEN 'T_STK_INSTOCKENTRY' THEN '源_采购入库单:'+ t2.FBILLNO
|
|
WHEN 'T_STK_STKTRANSFERINENTRY1' THEN (CASE t3.FPRICE WHEN 0 THEN '' ELSE '源_分步式调入单:'+ t3.FBILLNO END)
|
|
ELSE ''
|
|
END) AS 'newExplain'
|
|
,t0e_lk.FSTABLENAME
|
|
,t0e_lk.FDATE
|
|
,t0e_lk.FSTOCKID
|
|
,t0e_lk.inRow
|
|
,YEAR(t0e_lk.FDATE) * 100 + MONTH(t0e_lk.FDATE) AS DateNum
|
|
,t4.FMASTERID
|
|
,t4i.FINVPTYID
|
|
,t4i.FISAFFECTCOST
|
|
,t4i.FISENABLE
|
|
INTO #TMP_HAS_PARENT_MIS
|
|
FROM #TMP_DATA t0e_lk
|
|
OUTER APPLY (
|
|
SELECT t1.FBILLNO,t1e.FPRICE
|
|
FROM T_STK_MISDELIVERY t1 --其他出库单
|
|
INNER JOIN T_STK_MISDELIVERYENTRY t1e on t1.FID = t1e.FID
|
|
AND (t1e.FMATERIALID = t0e_lk.FMATERIALID AND t1e.FID = t0e_lk.FSBILLID AND t1e.FENTRYID = t0e_lk.FSID AND t0e_lk.FSTABLENAME = 'T_STK_MISDELIVERYENTRY')
|
|
) t1
|
|
OUTER APPLY (
|
|
SELECT t2.FBILLNO,t2e_f.FPRICE
|
|
FROM T_STK_INSTOCK t2 --采购入库单
|
|
INNER JOIN T_STK_INSTOCKENTRY t2e on t2e.FID = t2.FID
|
|
INNER JOIN T_STK_INSTOCKENTRY_F t2e_f on t2e.FID = t2e_f.FID AND t2e.FENTRYID = t2e_f.FENTRYID
|
|
AND (t2e.FMATERIALID = t0e_lk.FMATERIALID AND t2e.FID = t0e_lk.FSBILLID AND t2e.FENTRYID = t0e_lk.FSID AND t0e_lk.FSTABLENAME = 'T_STK_INSTOCKENTRY')
|
|
) t2
|
|
OUTER APPLY (
|
|
SELECT t3.FBILLNO
|
|
,t3e.F_GAT_DECIMAL AS FPRICE
|
|
-- ,(CASE LTRIM(RTRIM(t3e.FReferPrice)) WHEN '' THEN 0 ELSE CONVERT(decimal(23,6) ,t3e.FReferPrice) END) AS FPRICE
|
|
FROM T_STK_STKTRANSFERIN t3 --分步式调入
|
|
INNER JOIN T_STK_STKTRANSFERINENTRY t3e on t3.FID = t3e.FID
|
|
AND (t3e.FMATERIALID = t0e_lk.FMATERIALID AND t3e.FID = t0e_lk.FSBILLID AND t3e.FENTRYID = t0e_lk.FSID AND t0e_lk.FSTABLENAME = 'T_STK_STKTRANSFERINENTRY1')
|
|
) t3
|
|
INNER JOIN T_BD_MATERIAL t4 on t4.FMATERIALID = t0e_lk.FMATERIALID
|
|
INNER JOIN T_BD_MATERIALINVPTY t4i on t0e_lk.FMATERIALID = t4i.FMATERIALID AND t4i.FINVPTYID = 10001 --AND t4i.FISENABLE = 1
|
|
WHERE 1 = 1
|
|
/***********************************取上游单据end********************************************/
|
|
/***********************************存货收发结存start***************************************************/
|
|
SELECT t0.FDATE
|
|
--,t0.FBILLNO,t0.FID,t0.FENTRYID
|
|
,t0.FMASTERID,t0.FMATERIALID,t0.FSTOCKID,t0.FINVPTYID,t0.FISAFFECTCOST,t0.FISENABLE
|
|
,t0.inRow
|
|
,ISNULL((CASE t0.newReferPrice WHEN 0
|
|
THEN (CASE WHEN t0.FISAFFECTCOST = 1 AND t0.FISENABLE = 1 THEN t2.FDATE ELSE t3.FDATE END)
|
|
ELSE t0.newExplain
|
|
END),'') AS 'newExplain'
|
|
,ISNULL((CASE t0.newReferPrice WHEN 0 THEN
|
|
(CASE WHEN t0.FISAFFECTCOST = 1 AND t0.FISENABLE = 1
|
|
THEN t2.PRICE
|
|
ELSE (CASE WHEN t3.FQTY <> 0 THEN ROUND(t3.FAMOUNT/t3.FQTY,6) ELSE 0 END)
|
|
END)
|
|
ELSE t0.newReferPrice
|
|
END),0) AS 'newReferPrice'
|
|
INTO #TMP_结存单价_END_LIST
|
|
FROM #TMP_HAS_PARENT_MIS t0
|
|
OUTER APPLY(
|
|
SELECT TOP 1 tt1.FDATE
|
|
,(CASE WHEN tt1.FQTY <> 0 THEN ROUND(tt1.FAMOUNT/tt1.FQTY,6) ELSE 0 END) AS PRICE
|
|
FROM V_MATERIAL_INIVSTOCKDIMENSION tt1
|
|
WHERE 1 = 1
|
|
AND t0.FMASTERID = tt1.FMASTERID
|
|
AND t0.FSTOCKID = tt1.FSTOCKID
|
|
AND tt1.DateNum <= t0.DateNum
|
|
AND (t0.FISENABLE = 1 AND t0.FISAFFECTCOST = 1)
|
|
AND t0.newReferPrice = 0
|
|
AND tt1.FQTY > 0
|
|
ORDER BY tt1.FYEAR DESC,tt1.FPERIOD DESC
|
|
) t2
|
|
OUTER APPLY (
|
|
SELECT TOP 1 tt2.FYEAR,tt2.FPERIOD
|
|
,CONVERT(nvarchar(10),FYEAR) + '.' + CONVERT(nvarchar(10),FPERIOD) AS FDATE
|
|
,SUM(tt2.FAMOUNT) AS FAMOUNT,SUM(tt2.FQTY) AS FQTY
|
|
FROM V_MATERIAL_INIVSTOCKDIMENSION tt2
|
|
WHERE 1 = 1
|
|
AND t0.FMASTERID = tt2.FMASTERID
|
|
AND tt2.DateNum <= t0.DateNum
|
|
AND (t0.FISENABLE = 0 OR t0.FISAFFECTCOST = 0)
|
|
AND t0.newReferPrice = 0
|
|
GROUP BY tt2.FYEAR,tt2.FPERIOD
|
|
HAVING SUM(tt2.FQTY) > 0
|
|
ORDER BY tt2.FYEAR DESC,tt2.FPERIOD DESC
|
|
) t3
|
|
|
|
/*****************************************存货收发结存end***********************************************/
|
|
/*****************************************合同单价、采购入库单start**********************************************/
|
|
SELECT t0.FDATE
|
|
--,t0.FBILLNO,t0.FID,t0.FENTRYID
|
|
,t0.FMASTERID,t0.FMATERIALID,t0.FSTOCKID,t0.FINVPTYID,t0.FISAFFECTCOST
|
|
,t0.inRow
|
|
,ISNULL((CASE WHEN t0.newReferPrice = 0
|
|
THEN (CASE WHEN t0.FISAFFECTCOST = 1 AND t0.FISENABLE = 1
|
|
THEN (CASE WHEN t1.FMATERIALID IS NOT NULL THEN t1.FPRICE ELSE t2.FPRICE END)
|
|
ELSE (CASE WHEN t2.FMATERIALID IS NOT NULL THEN t2.FPRICE ELSE t1.FPRICE END)
|
|
END)
|
|
ELSE t0.newReferPrice
|
|
END),0) AS 'newReferPrice'
|
|
,ISNULL((CASE WHEN t0.newReferPrice = 0
|
|
THEN (CASE WHEN t0.FISAFFECTCOST = 1 AND t0.FISENABLE = 1
|
|
THEN (CASE WHEN t1.FMATERIALID IS NOT NULL THEN '取采购入库单单价,单据:'+t1.FBILLNO ELSE '取合同价,合同号为:'+t2.FBILLNO END)
|
|
ELSE (CASE WHEN t2.FMATERIALID IS NOT NULL THEN '取合同价,合同号为:'+t2.FBILLNO ELSE '取采购入库单单价,单据:'+t1.FBILLNO END)
|
|
END)
|
|
ELSE t0.newExplain
|
|
END),'没有找到价格') AS 'newExplain'
|
|
FROM #TMP_结存单价_END_LIST t0
|
|
OUTER APPLY (
|
|
SELECT TOP 1 tt0.FBILLNO,tt0e.FMATERIALID,tt0e.FSTOCKID
|
|
,tt0e_f.FPRICE,tt0e_f.FCOSTPRICE
|
|
FROM T_STK_INSTOCK tt0 --采购入库
|
|
INNER JOIN T_STK_INSTOCKENTRY tt0e on tt0.FID = tt0e.FID
|
|
INNER JOIN T_STK_INSTOCKENTRY_F tt0e_f on tt0e.FENTRYID = tt0e_f.FENTRYID
|
|
WHERE
|
|
tt0.FDOCUMENTSTATUS = 'C'
|
|
AND tt0.FCANCELSTATUS = 'A'
|
|
AND tt0.FSTOCKORGID = 101542
|
|
AND (tt0e_f.FPRICE != 0 OR tt0e_f.FCOSTPRICE <> 0)
|
|
AND t0.FMATERIALID = tt0e.FMATERIALID AND tt0e.FSTOCKID = t0.FSTOCKID
|
|
AND DATEDIFF(DAY,tt0.FDATE, t0.FDATE) > -1
|
|
ORDER BY tt0.FDATE DESC
|
|
) t1
|
|
LEFT JOIN (
|
|
SELECT
|
|
tt0e.F_QNV_BASE1 AS FMATERIALID
|
|
--,tt0e.F_QNV_DECIMAL3 AS FPRICE--综合单价
|
|
--,tt0e.F_QNV_DECIMAL1 AS FPRICE--含税单价
|
|
,tt0e.F_QNV_PRICE AS FPRICE--不含税单价
|
|
,tt0.F_QNV_TEXT2 AS FBILLNO
|
|
,tt1.FMASTERID
|
|
,ROW_NUMBER() OVER (PARTITION BY tt1.FMASTERID ORDER BY F_QNV_DATE2 DESC, tt1.FUSEORGID DESC) 'RN'
|
|
FROM QNV_t_Cust_Entry100003 tt0 --供应商年度合同
|
|
INNER JOIN QNV_t_Cust_Entry100004 tt0e on tt0.FID = tt0e.FID
|
|
INNER JOIN T_BD_MATERIAL tt1 on tt1.FMATERIALID = tt0e.F_QNV_BASE1
|
|
WHERE 1 = 1
|
|
AND tt0.FDOCUMENTSTATUS = 'C'
|
|
AND tt0e.F_QNV_PRICE != 0
|
|
) t2 on t0.FMASTERID = t2.FMASTERID AND t2.RN = 1
|
|
/*****************************************合同单价、采购入库单end**********************************************/
|
|
|
|
DROP TABLE #TMP_DATA
|
|
DROP TABLE #TMP_HAS_PARENT_MIS
|
|
DROP TABLE #TMP_结存单价_END_LIST
|