You cannot select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
150 lines
6.7 KiB
Plaintext
150 lines
6.7 KiB
Plaintext
Select
|
|
HU1.Purch_Category1_Desc
|
|
,HU1.OP_START_DATE
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Scheduled_Resource END "Machine"
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Resource_Description END "Machine Description"
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Order_No END "Order No"
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Release_No END "Release No"
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Sequence_No END "Sequence No"
|
|
,CASE WHEN lag(HU1.CF$_Lot_Batch_No,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=CF$_Lot_Batch_No then '' ELSE HU1.Color END "Color"
|
|
,CASE WHEN lag(HU1.Part_NO,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=HU1.Part_NO then '' ELSE HU1.Part_NO END "Component Part"
|
|
,CASE WHEN lag(HU1.Part_NO,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=HU1.Part_NO then '' ELSE HU1.Legacy END "Legacy No"
|
|
,CASE WHEN lag(HU1.Part_NO,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=HU1.Part_NO then '' ELSE HU1.DESCRIPTION END "Component Description"
|
|
,CASE WHEN lag(HU1.Part_NO,1,0) OVER (Partition BY HU1.CF$_Lot_Batch_No ORDER BY HU1.Receipt_Date)=HU1.Part_NO then '' ELSE HU1.ISSUE_TYPE END "Reserve/Issue Method"
|
|
,HU1.Picking
|
|
,HU1.Qty_To_Move
|
|
,HU1.Location_No
|
|
,HU1.HU
|
|
,HU1.Lot_Batch
|
|
,HU1.Receipt_Date
|
|
,HU1.Location_Qty
|
|
,HU1.Location_Qty_Cumul
|
|
--,HU1.Cumul_To_Move
|
|
--,HU1.QTY_REMAIN_TO_ISSUE
|
|
|
|
|
|
From
|
|
(
|
|
Select
|
|
F1.CF$_Lot_Batch_No
|
|
,F1.Purch_Category1_Desc
|
|
,F1.OP_START_DATE
|
|
,F1.Scheduled_Resource
|
|
,F1.Resource_Description
|
|
,F1.Order_No
|
|
,F1.Release_No
|
|
,F1.Sequence_No
|
|
,IPC.Color
|
|
,F1.Part_NO
|
|
,F1.Legacy
|
|
,F1.DESCRIPTION
|
|
,F1.ISSUE_TYPE
|
|
,F1.Picking
|
|
,F1.Qty_To_Move
|
|
,F1.Location_No
|
|
,F1.HU
|
|
,F1.Lot_Batch
|
|
,F1.Receipt_Date
|
|
,F1.Location_Qty
|
|
,F1.Location_Qty_Cumul
|
|
,F1.Cumul_To_Move
|
|
,F1.QTY_REMAIN_TO_ISSUE
|
|
,ROW_NUMBER() OVER (PARTITION BY F1.HU,F1.Receipt_Date Order By F1.OP_START_DATE,F1.Part_NO,F1.Receipt_Date) CT_HU
|
|
|
|
From
|
|
(
|
|
|
|
Select
|
|
Lag3.*
|
|
,lag(Lag3.Location_Qty_Cumul,1,0) OVER (Partition BY Lag3.Part_NO ORDER BY Lag3.OP_START_DATE,Lag3.Receipt_Date) PREV_LOC_CUMUL
|
|
FROM
|
|
(Select
|
|
Lag2.*
|
|
,sum(Lag2.Location_Qty) OVER(PARTITION BY Lag2.Part_NO,Lag2.OP_START_DATE ORDER BY Lag2.OP_START_DATE,Lag2.Receipt_Date asc ROWS UNBOUNDED PRECEDING) Location_Qty_Cumul
|
|
From
|
|
(Select
|
|
Lag1.*
|
|
,TL.Location_No
|
|
,TL.HANDLING_UNIT_ID HU
|
|
,TL.LOT_BATCH_NO Lot_Batch
|
|
,TL.Receipt_Date
|
|
,TL.Location_Qty
|
|
|
|
From
|
|
(Select
|
|
PP.cf$_purchase_cat1_desc Purch_Category1_Desc
|
|
,SMA.Order_No
|
|
,SMA.Release_No
|
|
,SMA.Sequence_No
|
|
,SOO.CF$_Lot_Batch_No
|
|
,SOO.PART_NO Part_No_FG
|
|
,SOO.OP_START_DATE
|
|
,Machine_Operation_Load_API.Get_SO_Op_Resource_Id(SOO.ORDER_NO, SOO.RELEASE_NO, SOO.SEQUENCE_NO, SOO.OPERATION_NO) Scheduled_Resource
|
|
,WC.Description Resource_Description
|
|
,IP.Contract
|
|
,IP.Part_NO
|
|
,SMA.ISSUE_TYPE
|
|
,IP.Note_Text Legacy
|
|
,IP.Contract Site
|
|
,IP.DESCRIPTION
|
|
,nvl(TP.QtyOnHand,0) Picking
|
|
,SMA.QTY_REMAIN_TO_ISSUE- nvl(TFS.QtyOnHand,0) Qty_To_Move
|
|
,SMA.QTY_REMAIN_TO_ISSUE
|
|
,sum(SMA.QTY_REMAIN_TO_ISSUE) OVER(PARTITION BY IP.Part_NO ORDER BY SOO.OP_START_DATE asc ROWS UNBOUNDED PRECEDING) - nvl(TFS.QtyOnHand,0) Cumul_To_Move
|
|
|
|
|
|
From
|
|
SHOP_MATERIAL_ALLOC_uiv_cfv SMA
|
|
|
|
inner join SHOP_ORDER_OPERATION_cfv SOO on SMA.Order_No=SOO.Order_No and SMA.Release_No=SOO.Release_No and SMA.Sequence_No=SOO.Sequence_No
|
|
|
|
inner join INVENTORY_PART IP on SMA.PART_NO=IP.PART_NO and SMA.CONTRACT=IP.CONTRACT
|
|
|
|
left join PURCHASE_PART_cfv PP on IP.Part_No=PP.Part_No and IP.Contract=PP.Contract
|
|
|
|
left join WORK_CENTER_RESOURCE WC on WC.Contract=SOO.Contract and WC.RESOURCE_ID=Machine_Operation_Load_API.Get_SO_Op_Resource_Id(SOO.ORDER_NO, SOO.RELEASE_NO, SOO.SEQUENCE_NO, SOO.OPERATION_NO)
|
|
|
|
left join
|
|
(select PART_NO, CONTRACT, sum(QTY_ONHAND) QtyOnHand from Inventory_Part_in_Stock_uiv where AVAILABILITY_CONTROL_ID is null and LOCATION_TYPE_db='F' and QTY_ONHAND>0 Group By Contract, PART_NO
|
|
) TFS on SMA.Part_No=TFS.PART_NO and SMA.Contract=TFS.Contract
|
|
|
|
left join
|
|
(select PART_NO, CONTRACT, sum(QTY_ONHAND) QtyOnHand from Inventory_Part_in_Stock_uiv where AVAILABILITY_CONTROL_ID is null and LOCATION_TYPE_db='PICKING' and QTY_ONHAND>0 Group By Contract, PART_NO
|
|
) TP on SMA.Part_No=TP.PART_NO and SMA.Contract=TP.Contract
|
|
|
|
|
|
|
|
Where
|
|
IP.CONTRACT LIKE '%&Contract%'
|
|
and report_sys.parse_parameter(PP.cf$_purchase_part_cat_1, '&[-C-BL]PurchasedCategory') = 'TRUE'
|
|
and SMA.State not in ('Cancelled','Closed','Planned')
|
|
and SMA.ISSUE_TYPE_db not in ('MANUAL')
|
|
and SMA.CF$_BACKFLUSH_PART in ('Only Floor Stock','Only Specified Location')
|
|
and SOO.OP_START_DATE<(sysdate+('&Begin_within_x_hours')/24)
|
|
and (SMA.QTY_REMAIN_TO_ISSUE- nvl(TFS.QtyOnHand,0)) >0
|
|
-- and TL.Location_Qty>0 They d want to see shop orders for which they do not have the stock available
|
|
and SOO.Operation_No='10'
|
|
and Machine_Operation_Load_API.Get_SO_Op_Resource_Id(SOO.ORDER_NO, SOO.RELEASE_NO, SOO.SEQUENCE_NO, SOO.OPERATION_NO) LIKE NVL('%&Machine%','%')
|
|
) Lag1
|
|
|
|
left join
|
|
(select PART_NO, CONTRACT, Location_No, RECEIPT_DATE, HANDLING_UNIT_ID, LOT_BATCH_NO, sum(QTY_ONHAND) Location_Qty from Inventory_Part_in_Stock_uiv where AVAILABILITY_CONTROL_ID is null and LOCATION_TYPE_db='PICKING' Group By Contract, PART_NO,Location_No, RECEIPT_DATE, HANDLING_UNIT_ID, LOT_BATCH_NO
|
|
) TL on TL.Part_No=Lag1.PART_NO and TL.Contract=Lag1.Contract
|
|
) Lag2
|
|
) Lag3
|
|
|
|
) F1
|
|
|
|
left join
|
|
(Select Contract,Part_No, ATTR_VALUE_ALPHA Color from INVENTORY_PART_CHAR_ALL where CHARACTERISTIC_CODE in ('00028')
|
|
) IPC on IPC.Contract=F1.Site and IPC.Part_No=F1.Part_No_FG
|
|
|
|
where PREV_LOC_CUMUL<=Cumul_To_Move
|
|
|
|
) HU1
|
|
Where CT_HU=1 -- Do not want duplicated lines having the same HU to be displayed.
|
|
Order by
|
|
HU1.OP_START_DATE
|
|
,HU1.Part_NO
|
|
,HU1.Receipt_Date asc
|
|
,HU1.Location_No |