Files
GateDge2023_ljy/03.珠海市汇威精密制造有限公司/HW.PythonPlugIn/ProductionMaterialsReport/sql/新BOM层级库存状态.sql
PastSaid 08d8878eef a
2024-03-11 14:47:23 +08:00

281 lines
7.5 KiB
Transact-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.

declare
@moBillNo varchar(100)
,@salesBillNo varchar(100)
,@startMaterialId int
,@endMaterialId int
,@FSDate varchar (30)
,@FEDate varchar (30)
,@FSNumber varchar (50)
,@FENumber varchar (50)
,@FSStock varchar (max)
SET @moBillNo =''
SET @salesBillNo =''
SET @moBillNo = 0
SET @moBillNo = 0
SET @FSDate = '2024-01-05'
SET @FEDate = '2024-02-05'
SET @FSNumber = '1.01'
SET @FENumber = '1.01'
--SET @FSNumber = 'TSH182H000208O'
--SET @FENumber = 'TSH182H000208O'
SET @FSStock =''
declare @FCloseBALDate varchar (30)
declare @FClosedate varchar (30)
--查询起始日期最近一期的期末结存日期
If NOT Exists(
SELECT FORGID, MAX(FCLOSEDATE) fclosedate
FROM T_STK_CLOSEPROFILE
WHERE FORGID IN (1) AND FCATEGORY = 'STK' AND (FCLOSEDATE < @FSDate)
GROUP BY FORGID)
BEGIN
SET @FClosedate='2020-01-01'
SET @FCloseBALDate='2020-01-01'
--print @FClosedate
END
ELSE
BEGIN
--SET @FClosedate='2019-07-01'
SELECT @FClosedate= CONVERT(varchar (30), DATEADD(D, 1,MAX(FCLOSEDATE)),23) FROM
T_STK_CLOSEPROFILE WHERE ((FORGID IN (1) AND FCATEGORY = 'STK') AND (FCLOSEDATE < @FSDate)) GROUP BY FORGID
SET @FCloseBALDate=CONVERT(varchar (30), DATEADD(D, -1,@FClosedate),23)
--print @FClosedat
END
DECLARE @FSWL varchar (50)
DECLARE @FEWL varchar (50)
SET @FSWL=''
SET @FEWL=''
IF @FSNumber<>'' and @FENumber<>''
BEGIN
SET @FSWL= @FSNumber
SET @FEWL= @FENumber
END
IF @FSNumber<>'' and @FENumber=''
BEGIN
SET @FSWL= @FSNumber
SELECT @FEWL=MAX(FNUMBER) FROM T_BD_MATERIAL
END
IF @FSNumber='' and @FENumber<>''
BEGIN
SET @FEWL= @FENumber
SELECT @FSWL=MIN(FNUMBER) FROM T_BD_MATERIAL
END
IF @FSNumber='' and @FENumber=''
BEGIN
SELECT @FSWL=MIN(FNUMBER) FROM T_BD_MATERIAL
SELECT @FEWL=MAX(FNUMBER) FROM T_BD_MATERIAL
END
--生成临时选取仓库
IF EXISTS(select * FROM tempdb..SYSOBJECTS WHERE id=OBJECT_ID('tempdb..#tmpStockID'))
BEGIN
DROP TABLE #tmpStockID
print '存在'
END
Create Table #tmpStockID (
FID INT IDENTITY(1,1)
,FStockID INT
)
DECLARE @Strsql varchar(max)
SET @Strsql= 'insert into #tmpStockID select distinct FSTOCKID from T_BD_STOCK where 1=1 ' +@FSStock
EXEC(@Strsql)
--库存状态报表
if exists(select * from tempdb..sysobjects where id=object_id('tempdb..#Stock_Status_temp'))
begin
drop table #Stock_Status_temp
print '存在'
end
Create Table #Stock_Status_temp (
序号 INT IDENTITY(1,1),
物料内码 INT ,
物料代码 varchar(100) null ,
物料名称 varchar(255) null ,
规格型号 varchar(255) null ,
旧编码 varchar(100) null ,
--单位 varchar(30) null ,
上期结存 DECIMAL (18, 2) Null ,
本期采购入库 DECIMAL (18, 2) Null ,
本期耗用 DECIMAL (18, 2) Null ,
期末结存 DECIMAL (18, 2) Null ,
在途量 DECIMAL (18, 2) Null ,
在制数 DECIMAL (18, 2) Null ,
进检量 DECIMAL (18, 2) Null ,
未发量 DECIMAL (18, 2) Null ,
领料数量 DECIMAL (18, 2) Null ,
销售出库数量 DECIMAL (18, 2) Null ,
仓库拨出数量 DECIMAL (18, 2) Null ,
仓库拨入数量 DECIMAL (18, 2) Null ,
申购未转数 DECIMAL (18, 2) Null,
受订量 DECIMAL (18, 2) Null ,
占用量 DECIMAL (18, 2) Null ,
可用库存 DECIMAL (18, 2) Null ,
仓库内码 INT ,
仓库代码 varchar(100) null ,
仓库名称 varchar(255) null ,
包装内码 INT ,
包装方式 varchar(255) null
)
if exists(select * from tempdb..sysobjects where id=object_id('tempdb..#TMP'))
begin
drop table #TMP
print '存在'
end
CREATE TABLE #TMP (
FID INT IDENTITY(1,1),
FSTOCKORGID INT NOT NULL DEFAULT 0,
FBILLENTRYID INT NOT NULL DEFAULT 0,
FORDERBY INT NOT NULL DEFAULT 0,
FSTOCKIO CHAR (1) NULL,
FMATERIALID INT NOT NULL DEFAULT 0,
FAUXPROPID INT NOT NULL DEFAULT 0,
FDATE DATETIME NULL,
FSTOCKID INT NOT NULL DEFAULT 0,
FSTOCKLOCID INT NOT NULL DEFAULT 0,
FSTOCKSTATUSID INT NOT NULL DEFAULT 0,
FBILLNAME NVARCHAR (100) NULL,
FBILLID INT NOT NULL DEFAULT 0,
FBILLSEQID INT NULL,
FBILLNO NVARCHAR (100) NULL,
FBASEQCQTY DECIMAL (23, 10) NOT NULL DEFAULT 0,
FBASEINQTY DECIMAL (23, 10) NOT NULL DEFAULT 0,
FBASEOUTQTY DECIMAL (23, 10) NOT NULL DEFAULT 0
)
--分析BOM层级物料
IF EXISTS(SELECT * FROM TEMPDB..SYSOBJECTS WHERE ID=OBJECT_ID('TEMPDB..#YC_T_MRP'))
BEGIN
DROP TABLE #YC_T_MRP
END
CREATE TABLE #YC_T_MRP(
FID INT IDENTITY(1,1),
FBOMNumber NVARCHAR(255),
FMATERIALID INT,
物料编码 NVARCHAR(255),
物料名称 NVARCHAR(255),
成品率 DECIMAL(28,10) DEFAULT (0),
分子 DECIMAL(28,10),--BOM分子
分母 DECIMAL(28,10),--BOM分母
FQty DECIMAL(28,10),--用量
FLevle INT ,
FERPCLSID INT,
FOrderNum NVARCHAR(255),
FBOMID INT,
BOM层级 NVARCHAR(200) NULL,
FSEQ1 INT,
FSEQ2 INT,
FSEQ3 INT,
FSEQ4 INT,
FSEQ5 INT,
FSEQ6 INT,
FParentNumber NVARCHAR(255)
)
IF EXISTS(SELECT * FROM TEMPDB..SYSOBJECTS WHERE ID=OBJECT_ID('TEMPDB..#BOMTMP'))
BEGIN
DROP TABLE #BOMTMP
END
/*取出所有审核状态的BOM放入临时表中*/
SELECT
ID=IDENTITY(INT,1,1)
,T0.FID
,T0.FNUMBER
,T0.FMATERIALID
,ROW_NUMBER() OVER(PARTITION BY T0.FMATERIALID ORDER BY t0.FID DESC) AS ROWID
INTO #BOMTmp
FROM T_ENG_BOM T0
INNER JOIN T_BD_MATERIAL TM ON t0.FMATERIALID=TM.FMATERIALID --物料表
WHERE (t0.FDOCUMENTSTATUS = 'C') and (t0.FFORBIDSTATUS='A')
AND (TM.FNUMBER >= @FSWL AND TM.FNUMBER <=@FEWL)
ORDER BY FMATERIALID,FNUMBER
--/*在临时表中同一个物料代码只保留一个最新版本的BOM*/
--DELETE FROM #BOMTmp WHERE id NOT IN (SELECT max(id) FROM #BOMTmp GROUP BY FMATERIALID)
DELETE FROM #BOMTmp WHERE ROWID > 1
IF EXISTS(SELECT * FROM TEMPDB..SYSOBJECTS WHERE ID=OBJECT_ID('TEMPDB..#TMP_TOP_BOM_SET'))
BEGIN
DROP TABLE #TMP_TOP_BOM_SET
END
CREATE TABLE #TMP_TOP_BOM_SET(
FID int
,FNUMBER varchar(80)
,FMATERIALID int
,FSEQ int
,BOMLEVEL int
,TOPID int
,showlevel varchar(80)
,BOMID int
,FERPCLSID int
)
CREATE INDEX [#TMP_TOP_BOM_SET_FID] ON #TMP_TOP_BOM_SET(FID);
INSERT INTO #TMP_TOP_BOM_SET
SELECT
t0.FID
,t1.FNUMBER
,t0.FMATERIALID
,ROW_NUMBER() over(partition BY t0.FID order by t0.fid)
,1 'BOMLEVEL'
,t0.FID AS 'TOPID'
,''
,t0.FID AS 'BOMID'
,t2.FERPCLSID
FROM T_ENG_BOM t0
INNER JOIN T_BD_MATERIAL t1 on t0.FMATERIALID = t1.FMATERIALID
LEFT OUTER JOIN t_BD_MaterialBase t2 ON t1.FMATERIALID = t2.FMATERIALID
INNER JOIN #BOMTmp t3 on t3.FNUMBER = t0.FNUMBER AND t3.FMATERIALID = t0.FMATERIALID
WHERE 1 = 1
AND (t0.FDOCUMENTSTATUS = 'C')
DECLARE @num INT,@level int,@LoopCount int
SET @num = 1
SET @level =1
SET @LoopCount = 0;
WHILE (@num > 0 AND @LoopCount < 10)
BEGIN
INSERT INTO #TMP_TOP_BOM_SET
SELECT
t3.FID
,t2.FNUMBER
,t1.FMATERIALID
,ROW_NUMBER() over(partition BY t0.TOPID,t0.bomid order by t0.fseq) 'FSEQ'
,@level + 1 AS 'BOMLEVEL'
,t0.TOPID
,CONCAT(t0.showlevel,'-',CAST(dense_rank() over(partition BY t0.topid,t0.bomid,t0.fid order by t1.fseq) as VARCHAR)) 'showLevel'
,0 'OID'
,t4.FERPCLSID
FROM
#TMP_TOP_BOM_SET t0
LEFT JOIN T_ENG_BOMCHILD t1 on t0.BOMID = t1.FID
INNER JOIN T_BD_MATERIAL t2 on t2.FMATERIALID = t1.FMATERIALID
LEFT JOIN T_BD_MATERIAL_L t1_l on t1_l.FMATERIALID = t1.FMATERIALID AND t1_l.FLOCALEID = 2052
LEFT JOIN T_ENG_BOM t3 on t1.FID = t3.FID--t1.FMATERIALID = t3.FMATERIALID
LEFT JOIN T_BD_MATERIALBASE t4 on t4.FMATERIALID = t1.FMATERIALID
WHERE 1 = 1
--AND (t2.FERPCLSID = 2 OR t2.FERPCLSID = 5 )
AND t0.FERPCLSID >= 2
AND t0.BOMLEVEL = @level
AND t3.FDOCUMENTSTATUS = 'C'
AND t2.FFORBIDSTATUS = 'A'
SET @num = @@ROWCOUNT
SET @level += 1
SET @LoopCount += 1
END
SELECT * FROM #TMP_TOP_BOM_SET