66 lines
3.5 KiB
SQL
66 lines
3.5 KiB
SQL
WITH #年度 AS (
|
|
SELECT t0.FBILLNO,'年度预测单' AS '需求类型',t0.FVERSIONS,t0.FCRMBILLNO,t0.FDATE,t0.FFORECASTYEAR
|
|
,t0e.FMATERIALID,t0e.FCUSTID,t0e.FSEQ
|
|
,t0e.FMONTH1 + t0e.FMONTH2 + t0e.FMONTH3 + t0e.FMONTH4 + t0e.FMONTH5 + t0e.FMONTH6 + t0e.FMONTH7 + t0e.FMONTH8 + t0e.FMONTH9 + t0e.FMONTH10 + t0e.FMONTH11 + t0e.FMONTH12 AS 'QTY'
|
|
,DENSE_RANK() OVER (ORDER BY t0.FFORECASTYEAR DESC,t0.FBILLNO DESC,t0.FVERSIONS DESC) RN
|
|
FROM T_PLN_FORECAST2YEAR t0
|
|
INNER JOIN T_PLN_FORECAST2YEARENTRY t0e on t0.FID = t0e.FID
|
|
WHERE t0.FDOCUMENTSTATUS = 'C'
|
|
)
|
|
,#年度预测单 AS (
|
|
SELECT t0.需求类型,t0.FDATE '变更日期',t0.FMATERIALID,t0.FCUSTID,t1.FDATE '需求日期',t1.FVERSIONS '变更前版本号',t1.QTY '变更前',t0.FVERSIONS '变更后版本号',t0.QTY '变更后', t1.QTY - ISNULL(t0.QTY, 0) '差异数量'
|
|
FROM #年度 t0
|
|
INNER JOIN #年度 t1 on t0.FFORECASTYEAR = t1.FFORECASTYEAR AND t1.RN = 2
|
|
AND t0.FMATERIALID = t1.FMATERIALID
|
|
WHERE t0.RN = 1
|
|
)
|
|
,#N_3 AS (
|
|
SELECT t0.FBILLNO,'N+3' AS '需求类型',t0.FVERSIONS,t0.FCRMBILLNO,t0.FDATE,t0.FFORECASTYEAR,t0.FFORECASTMONTH
|
|
,t0e.FMATERIALID,t0e.FCUSTID,t0e.FSEQ
|
|
,t0e.FN0 + t0e.FN1 + t0e.FN2 + t0e.FN3 AS 'QTY'
|
|
,DENSE_RANK() OVER (PARTITION BY t0.FFORECASTYEAR,t0.FFORECASTMONTH ORDER BY t0.FVERSIONS DESC) RN
|
|
FROM T_PLN_FORECAST2N3 t0
|
|
INNER JOIN T_PLN_FORECAST2N3ENTRY t0e on t0.FID = t0e.FID
|
|
WHERE t0.FDOCUMENTSTATUS = 'C'
|
|
)
|
|
,#N_3预测单 AS (
|
|
SELECT t0.需求类型,t0.FDATE '变更日期',t0.FMATERIALID,t0.FCUSTID,t1.FDATE '需求日期',t1.FVERSIONS '变更前版本号',t1.QTY '变更前',t0.FVERSIONS '变更后版本号',t0.QTY '变更后', t1.QTY - ISNULL(t0.QTY, 0) '差异数量'
|
|
FROM #N_3 t0
|
|
INNER JOIN #N_3 t1 on t1.RN = 2
|
|
AND t0.FFORECASTYEAR = t1.FFORECASTYEAR AND t0.FFORECASTMONTH = t1.FFORECASTMONTH
|
|
AND t0.FMATERIALID = t1.FMATERIALID
|
|
WHERE t0.RN = 1
|
|
)
|
|
,#W_5 AS (
|
|
SELECT t0.FBILLNO,'W+5' AS '需求类型',t0.FVERSIONS,t0.FCRMBILLNO,t0.FDATE
|
|
,t0e.FMATERIALID,t0e.FCUSTID,t0e.FSEQ,t0.FFORECASTYEAR,t0e.FSTARTDATE
|
|
,t0e.FD1+t0e.FD2+t0e.FD3+t0e.FD4+t0e.FD5+t0e.FD6+t0e.FD7+t0e.FD8+t0e.FD9+t0e.FD10+t0e.FD11+t0e.FD12+t0e.FD13+t0e.FD14+t0e.FD15+t0e.FD16+t0e.FD17+t0e.FD18+t0e.FD19+t0e.FD20+t0e.FD21+t0e.FD22+t0e.FD23+t0e.FD24+t0e.FD25+t0e.FD26+t0e.FD27+t0e.FD28+t0e.FD29+t0e.FD30+t0e.FD31+t0e.FD32+t0e.FD33+t0e.FD34+t0e.FD35+t0e.FD36+t0e.FD37+t0e.FD38+t0e.FD39+t0e.FD40+t0e.FD41+t0e.FD42 AS 'QTY'
|
|
,DENSE_RANK() OVER (PARTITION BY t0.FFORECASTYEAR,t0e.FSTARTDATE ORDER BY t0.FBILLNO DESC,t0.FVERSIONS DESC) RN
|
|
FROM T_PLN_FORECAST2W5 t0
|
|
INNER JOIN T_PLN_FORECAST2W5ENTRY t0e on t0.FID = t0e.FID
|
|
WHERE t0.FDOCUMENTSTATUS = 'C'
|
|
)
|
|
,#W_5预测单 AS (
|
|
SELECT t0.需求类型,t0.FDATE '变更日期',t0.FMATERIALID,t0.FCUSTID,t1.FDATE '需求日期',t1.FVERSIONS '变更前版本号',t1.QTY '变更前',t0.FVERSIONS '变更后版本号',t0.QTY '变更后', t1.QTY - ISNULL(t0.QTY, 0) '差异数量'
|
|
FROM #W_5 t0
|
|
INNER JOIN #W_5 t1 on t1.RN = 2
|
|
AND t0.FFORECASTYEAR = t1.FFORECASTYEAR
|
|
AND t0.FSTARTDATE = t1.FSTARTDATE
|
|
AND t0.FMATERIALID = t1.FMATERIALID
|
|
WHERE t0.RN = 1
|
|
)
|
|
, #整合 AS (
|
|
SELECT *
|
|
FROM #年度预测单
|
|
UNION ALL
|
|
SELECT *
|
|
FROM #N_3预测单
|
|
UNION ALL
|
|
SELECT *
|
|
FROM #W_5预测单
|
|
)
|
|
SELECT t0.需求类型,t0.变更日期,t1.FNUMBER '物料编码',t1_l.FNAME '物料名称','' '物料大类','' '产品类别','' '产品名称',t2_l.FNAME '客户','' '车型',t0.需求日期,t0.变更前版本号,t0.变更前,t0.变更后版本号,t0.变更后,t0.差异数量
|
|
FROM #整合 t0
|
|
INNER JOIN T_BD_MATERIAL t1 on t1.FMATERIALID = t0.FMATERIALID
|
|
INNER JOIN T_BD_MATERIAL_L t1_l on t1_l.FMATERIALID = t1.FMATERIALID AND t1_l.FLOCALEID = 2052
|
|
INNER JOIN T_BD_CUSTOMER_L t2_l on t2_l.FCUSTID = t0.FCUSTID |