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.
187 lines
9.1 KiB
MySQL
187 lines
9.1 KiB
MySQL
SELECT c.Order_id AS "Order Type",
|
|
TO_CHAR(c.REAL_SHIP_DATE, 'YYYY-MM-DD') AS "Last Actual Ship Date",
|
|
TO_CHAR(c.PLANNED_DUE_DATE, 'YYYY-MM-DD') AS "Planned Due Date",
|
|
c.Contract AS "Site",
|
|
c.Order_no AS "Order",
|
|
c.line_no AS "Line No",
|
|
c.Rel_no AS "Rel No",
|
|
c.Line_item_no AS "Line Item No",
|
|
c.SUPPLY_CODE AS "Supply Code",
|
|
c.Vendor_no AS "Supplier",
|
|
c.Customer_no AS "Customer",
|
|
c.customer_name as "Customer Name",
|
|
c.SHIP_ADDR_NO as "Delivery Address",
|
|
IFSAPP.CUSTOMER_INFO_ADDRESS_API.Get_Name(c.CUSTOMER_NO,
|
|
c.SHIP_ADDR_NO) as "Delivery Customer Name",
|
|
IFSAPP.CUSTOMER_ORDER_API.GET_CUSTOMER_PO_NO(c.ORDER_NO) as "Customer PO No",
|
|
c.order_state as "Order Status",
|
|
c.state as "Status",
|
|
to_char(c.date_entered, 'YYYY-MM-DD') as "Date Entered",
|
|
TRUNC(c.WANTED_DELIVERY_DATE) as "Wanted Delivery Date",
|
|
to_char(c.PLANNED_SHIP_DATE, 'YYYY-MM-DD') as "Planned Ship Date",
|
|
to_char(c.PROMISED_DELIVERY_DATE, 'YYYY-MM-DD') as "Promised Delivery Date",
|
|
TRUNC((c.DELIVERY_LEADTIME + sysdate) - 1) -
|
|
TRUNC(c.PROMISED_DELIVERY_DATE) as "Days Late",
|
|
c.catalog_no as "Part",
|
|
c.catalog_desc as "Part Description",
|
|
|
|
C.CUSTOMER_PART_NO "Customer Part No",
|
|
|
|
c.buy_qty_due as "Sales Qty",
|
|
c.QTY_ASSIGNED as "Reserved Qty",
|
|
c.QTY_ON_ORDER as "Pegged Qty",
|
|
|
|
USABLE.QTY_ONHAND "Usable Qty",
|
|
|
|
IFSAPP.Inventory_Part_In_Stock_API.Get_Inventory_Qty_Onhand(c.CONTRACT,
|
|
c.PART_NO,
|
|
NULL) as "Qty on Hand By Site ",
|
|
|
|
NVL(ONHAND.QTY_ONHAND, 0) AS "Qty On Hand by Company",
|
|
co.CF$_INCOMING_DISPATCH_QTY as "Incoming dispatch Qty",
|
|
/* c.BUY_QTY_DUE - DECODE(c.CATALOG_TYPE_DB, 'INV', c.QTY_SHIPPED, NULL) as "Qty to Deliver", */
|
|
co.CF$_REMAINING AS "Qty to Deliver",
|
|
/* ROUND((c.BUY_QTY_DUE / IFSAPP.PART_HANDLING_UNIT_API.Get_Max_Quantity_Capacity(c.catalog_no, 'PALLET', 'EA')),2) as "No of Pallets", */
|
|
ROUND(co.CF$_NO_OF_PALLETS, 2) as "No of Pallets",
|
|
ROUND(co.CF$_REMAINING / NVL(co.CF$_MAX_CAP_PER_PALLET, 1), 2) AS "Remaining Pallets",
|
|
c.LINE_TOTAL_WEIGHT as "Weight (KG)",
|
|
c.LINE_TOTAL_WEIGHT * co.CF$_REMAINING / c.BUY_QTY_DUE as "Remaining Weight (KG)",
|
|
|
|
IFSAPP.Reserve_Customer_Order_API.Get_Available_Qty(NVL(c.supply_site,
|
|
c.contract),
|
|
NVL(NVL(c.supply_site_part_no,
|
|
c.part_no),
|
|
c.catalog_no),
|
|
c.configuration_id,
|
|
c.order_no,
|
|
c.line_no,
|
|
c.rel_no,
|
|
c.line_item_no,
|
|
c.supply_code_db,
|
|
c.part_ownership_db,
|
|
c.owning_customer_no,
|
|
c.project_id,
|
|
c.condition_code,
|
|
NULL,
|
|
'TRUE') as "Available Qty",
|
|
IFSAPP.Inventory_Part_In_Stock_API.Get_Inventory_Qty_Onhand(c.CONTRACT,
|
|
c.PART_NO,
|
|
NULL) -
|
|
sum(c.BUY_QTY_DUE -
|
|
DECODE(c.CATALOG_TYPE_DB, 'INV', c.QTY_SHIPPED, NULL)) over(PARTITION BY c.catalog_no ORDER BY c.catalog_no, c.PLANNED_SHIP_DATE rows UNBOUNDED PRECEDING) "Projected on Hand",
|
|
|
|
NVL(USABLE.QTY_ONHAND, 0) -
|
|
sum(c.BUY_QTY_DUE -
|
|
DECODE(c.CATALOG_TYPE_DB, 'INV', c.QTY_SHIPPED, NULL)) over(PARTITION BY c.catalog_no ORDER BY c.catalog_no, c.PLANNED_SHIP_DATE rows UNBOUNDED PRECEDING) "Projected Usable Qty",
|
|
|
|
IFSAPP.Customer_Order_Line_API.Get_Base_Sale_Price_Total(C.ORDER_NO,
|
|
c.LINE_NO,
|
|
c.REL_NO,
|
|
c.LINE_ITEM_NO) as "Value (curr)",
|
|
c.Currency_code as "Currency",
|
|
c.DELIVERY_TERMS as "Del Terms",
|
|
IFSAPP.Order_Delivery_Term_API.Get_Description(c.DELIVERY_TERMS) as "Del Term Desc",
|
|
IFSAPP.ORDER_COORDINATOR_API.Get_Name(IFSAPP.CUSTOMER_ORDER_API.Get_Authorize_Code(c.order_no)) as "Coordinator",
|
|
IFSAPP.PERSON_INFO_API.Get_Name(IFSAPP.CRM_CUST_INFO_API.Get_Main_Representative_Id(c.customer_no)) as "Main Rep",
|
|
IFSAPP.Customer_Group_API.Get_Description(IFSAPP.CUST_ORD_CUSTOMER_API.get_cust_grp(c.customer_no)) as "Cust Stat Group",
|
|
IFSAPP.SALES_DISTRICT_API.get_description(c.DISTRICT_CODE) as "Sales District",
|
|
c.CF$_COORDINATOR as "Coordinator ID",
|
|
c.CF$_next_prod_due_Date as "Next Production Due Date",
|
|
c.CF$_open_qty_shop_order as "Open Qty Shop Order",
|
|
c.CF$_BACKORDER_OPTION as "Backorder Option",
|
|
a.ADDRESS1,
|
|
a.ADDRESS2,
|
|
a.ZIP_CODE,
|
|
a.CITY,
|
|
a.COUNTY,
|
|
a.COUNTRY,
|
|
co.CF$_IML AS "IML",
|
|
co.CF$_IML_AVAILABLE AS "IML QTY",
|
|
IMP.IML_IN_ORDER AS "IML ON ORDER",
|
|
to_Char(ND.Next_Date, 'YYYY-MM-DD HH24:MI') AS "Next date",
|
|
ch.attr_value AS "Mold",
|
|
cd.attr_value AS "Decoration"
|
|
|
|
FROM IFSAPP.Site s
|
|
INNER JOIN IFSAPP.Customer_order_line_cfv co
|
|
ON co.contract = s.contract
|
|
INNER JOIN IFSAPP.Customer_order_join_cfv c
|
|
ON c.Order_no = co.Order_no
|
|
AND c.Line_no = co.Line_no
|
|
and c.Rel_no = co.Rel_no
|
|
AND c.Contract = co.Contract
|
|
|
|
LEFT JOIN IFSAPP.Customer_info_address a
|
|
ON c.Customer_No = a.Customer_ID
|
|
AND c.SHIP_ADDR_NO = a.Address_ID
|
|
INNER JOIN IFSAPP.Inventory_part_cfv inv
|
|
ON inv.Contract = c.Contract
|
|
AND inv.Part_no = c.Part_no
|
|
LEFT JOIN IFSAPP.Inventory_part_char_all ch
|
|
ON ch.Contract = inv.Contract
|
|
AND ch.Part_no = inv.Part_no
|
|
AND ch.CHARACTERISTIC_CODE = '00150'
|
|
LEFT JOIN IFSAPP.Inventory_part_char_all cd
|
|
ON cd.Contract = inv.Contract
|
|
AND cd.Part_no = inv.Part_no
|
|
AND cd.CHARACTERISTIC_CODE = '00034'
|
|
|
|
OUTER APPLY (SELECT SUM(QTY_ONHAND) AS QTY_ONHAND
|
|
from IFSAPP.Inventory_Part_in_Stock st
|
|
inner join ifsapp.site site
|
|
on site.company = s.company
|
|
and site.contract = st.contract
|
|
and st.Part_No = co.Part_no
|
|
group by st.Part_no) ONHAND
|
|
|
|
left join (Select Contract, Part_No, SUM(QTY_ONHAND) AS QTY_ONHAND
|
|
from IFSAPP.Inventory_Part_in_Stock
|
|
where AVAILABILITY_CONTROL_ID is null
|
|
or AVAILABILITY_CONTROL_ID in
|
|
('WAREHOUSE_LOCK_RES',
|
|
'BACKFLUSH_BLOCK',
|
|
'PARTIALS_AUTO_BLOCK',
|
|
'HANDL_UNIT_ON_SHOP_ORDER',
|
|
'RESERVE_BLOCK')
|
|
group by Part_no, contract) USABLE
|
|
on USABLE.Contract = inv.Contract
|
|
and USABLE.Part_No = inv.Part_No
|
|
|
|
OUTER APPLY (SELECT sum(CF$_REM_QTY_RECEIVE) AS IML_IN_ORDER
|
|
FROM IFSAPP.Purchase_Order_line_cfv pp
|
|
WHERE pp.PART_NO = co.CF$_IML
|
|
AND s.contract = pp.Contract
|
|
AND State NOT IN ('Closed', 'Cancelled')
|
|
AND CF$_REM_QTY_RECEIVE > 0
|
|
GROUP BY Part_No) IMP
|
|
|
|
OUTER APPLY (SELECT MIN(Planned_receipt_date) AS Next_date
|
|
FROM IFSAPP.Purchase_Order_line_cfv pp
|
|
WHERE pp.Part_no = co.CF$_IML
|
|
AND s.contract = pp.Contract
|
|
AND State NOT IN ('Closed', 'Cancelled')
|
|
AND CF$_REM_QTY_RECEIVE > 0
|
|
AND Part_no IS NOT NULL
|
|
GROUP BY Part_No) ND
|
|
|
|
WHERE s.Company = '&[MC--L]Company'
|
|
AND (s.Contract in
|
|
(SELECT REGEXP_SUBSTR(d__.str, '[^;]+', 1, LEVEL) AS val_
|
|
FROM (SELECT '&[-C--L]Site' AS str FROM DUAL) d__
|
|
CONNECT BY LEVEL <= REGEXP_COUNT(d__.str, ';') + 1) OR
|
|
s.Contract LIKE NVL('&[-C--L]Site', '%'))
|
|
AND c.Customer_no LIKE NVL('&Customer', '%')
|
|
AND c.SHIP_ADDR_NO LIKE NVL('&Ship_To', '%')
|
|
AND (ch.attr_value LIKE NVL('&Mold', '%') OR '&Mold' is null)
|
|
AND c.CF$_COORDINATOR LIKE
|
|
NVL('%&AUTHORIZE_CODE%', '%')
|
|
AND c.State not in ('Cancelled', 'Delivered', 'Invoiced/Closed')
|
|
AND c.Customer_no NOT LIKE 'W00%'
|
|
ORDER BY c.contract,
|
|
c.PLANNED_SHIP_DATE,
|
|
c.promised_delivery_date,
|
|
c.order_no,
|
|
c.line_no,
|
|
c.Rel_no
|
|
|
|
-- Lov reference is removed due to limitations in IFS cloud |