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.

215 lines
7.9 KiB
XML

<QUICK_REPORT_LIST><QUICK_REPORT state="queried" OBJ_ID="AAASXSAASAAAefoAAA" OBJ_VERSION="2025-07-25">
<QUICK_REPORT_ID datatype="Number">674035</QUICK_REPORT_ID>
<DESCRIPTION datatype="Text">Planning Bill Analysis</DESCRIPTION>
<SQL_EXPRESSION datatype="Text">Select
PB.COMPANY
,PB.CONTRACT
,C150.ATTR_VALUE_ALPHA &quot;Part Commodity&quot;
,C034.ATTR_VALUE_ALPHA &quot;Part Decoration&quot;
,IP.TYPE_DESIGNATION &quot;Type Designation&quot;
,PB.CATALOG_NO
,PB.CATALOG_DESC &quot;Part Description&quot;
,PB.REAL_SHIP_DATE
,PB.ORDER_NO
,PB.LINE_NO
,PB.REL_NO
,PB.CUSTOMER_NO
,PB.NAME &quot;Customer Name&quot;
,PB.Qty
,C150L.ATTR_VALUE_ALPHA &quot;Level Part Commodity&quot;
,C034L.ATTR_VALUE_ALPHA &quot;Level Part Decoration&quot;
,&quot;Level&quot;
,IP2.TYPE_DESIGNATION &quot;Level Part Type Designation&quot;
,PB.Level_Part_No
,IP2.Description &quot;Level Part Description&quot;
,PB.Qty_Extended &quot;Qty Extended&quot;
From
(
Select
CS.COMPANY
,CO.CONTRACT
,CO.CATALOG_NO
,CO.CATALOG_DESC
,CO.REAL_SHIP_DATE
,CO.ORDER_NO
,CO.LINE_NO
,CO.REL_NO
,CO.CUSTOMER_NO
,CU.NAME
,DECODE(CO.CATALOG_TYPE_DB, &apos;INV&apos;, CO.QTY_SHIPPED, NULL) Qty
,CO.CATALOG_NO Level_Part_No
,DECODE(CO.CATALOG_TYPE_DB, &apos;INV&apos;, CO.QTY_SHIPPED, NULL) Qty_Extended
,0 as &quot;Level&quot;
From CUSTOMER_ORDER_LINE CO
inner join COMPANY_SITE CS on CS.CONTRACT=CO.CONTRACT and CO.STATE in (&apos;Delivered&apos;,&apos;Partially Delivered&apos;,&apos;Invoiced/Closed&apos;)
inner join CUSTOMER_INFO CU on CU.CUSTOMER_ID=CO.CUSTOMER_NO
Where CS.COMPANY in &apos;&amp;Company&apos; and CO.Contract like nvl (&apos;&amp;Contract&apos;,&apos;%&apos;) and CATALOG_NO like trim(nvl (&apos;&amp;Part_No&apos;,&apos;%&apos;)) and trunc(CO.REAL_SHIP_DATE) BETWEEN TO_DATE(&apos;&amp;DATE_FROM&apos;,&apos;YYYY-MM-DD&apos;) AND TO_DATE (&apos;&amp;DATE_TO&apos;,&apos;YYYY-MM-DD&apos;)
and length(CO.CUSTOMER_NO)&gt;5
UNION
Select
CS.COMPANY
,CO.CONTRACT
,CO.CATALOG_NO
,CO.CATALOG_DESC
,CO.REAL_SHIP_DATE
,CO.ORDER_NO
,CO.LINE_NO
,CO.REL_NO
,CO.CUSTOMER_NO
,CU.NAME
,DECODE(CO.CATALOG_TYPE_DB, &apos;INV&apos;, CO.QTY_SHIPPED, NULL) Qty
,ML.Component_Part Level_Part_No
,DECODE(CO.CATALOG_TYPE_DB, &apos;INV&apos;, CO.QTY_SHIPPED, NULL)*ML.Qty_Per_Extended Qty_Extended
,Level_ as &quot;Level&quot;
From CUSTOMER_ORDER_LINE CO
inner join COMPANY_SITE CS on CS.CONTRACT=CO.CONTRACT and CO.STATE in (&apos;Delivered&apos;,&apos;Partially Delivered&apos;,&apos;Invoiced/Closed&apos;)
inner join CUSTOMER_INFO CU on CU.CUSTOMER_ID=CO.CUSTOMER_NO
inner join
(
Select
RC.contract
,RC.Root_Part_No
,IP.Description &quot;Description_Root_Part_No&quot;
,RC.Level_
,RC.PART_NO
,substr(RC.Chemin,2,100) Structure_Path
,RC.Component_Part
,RC.QTY_PER_ASSEMBLY
,RC.Qty_Per_Extended
from ifsapp.Inventory_Part IP
inner join
(
Select
MS.Contract
,CONNECT_BY_ROOT MS.PART_NO Root_Part_No
,LEVEL Level_
,MS.PART_NO
,MS.COMPONENT_PART
,SYS_CONNECT_BY_PATH(MS.PART_NO, &apos;_&apos;) Chemin
,MS.QTY_PER_ASSEMBLY
,XMLQUERY ( (&apos;1&apos; || SYS_CONNECT_BY_PATH (MS.QTY_PER_ASSEMBLY, &apos;*&apos;))
RETURNING CONTENT
).getnumberval () AS Qty_Per_Extended
,A.Alternative_No
from
ifsapp.MANUF_STRUCTURE_cfv MS
inner join ifsapp.MANUF_STRUCT_ALTERNATE A
on MS.Contract=A.Contract
and MS.PART_NO=A.PART_NO and MS.ALTERNATIVE_NO=A.ALTERNATIVE_NO
and MS.ENG_CHG_LEVEL=A.ENG_CHG_LEVEL and MS.BOM_TYPE=A.BOM_TYPE
and A.STATE=&apos;Buildable&apos;
inner join ifsapp.INVENTORY_PART IP on IP.Contract=MS.Contract and IP.Part_No=MS.Component_Part
inner join ifsapp.INVENTORY_PART_PLANNING IPP on IPP.Contract=MS.Contract and IPP.Part_No=MS.Component_Part
where MS.BOM_TYPE_DB=&apos;M&apos;
and EFF_PHASE_OUT_DATE is null
and MS.Contract like nvl (&apos;&amp;Contract&apos;,&apos;%&apos;)
and CONNECT_BY_ROOT MS.PART_NO like nvl (&apos;&amp;Part_No&apos;,&apos;%&apos;)
and MS.ALTERNATIVE_NO =&apos;*&apos;
and IP.TYPE_CODE_DB in (&apos;1&apos;,&apos;2&apos;)
and IP.PART_STATUS = &apos;A&apos;
and IP.ACCOUNTING_GROUP in (&apos;MFG&apos;,&apos;COMP&apos;)
and IPP.PLANNING_METHOD in (&apos;A&apos;,&apos;G&apos;)
and MS.COMPONENT_PART not in (&apos;1006628&apos;,&apos;1054478&apos;)
CONNECT BY
PRIOR MS.COMPONENT_PART=MS.PART_NO
and PRIOR MS.component_contract = MS.contract
and PRIOR MS.ALTERNATIVE_NO=MS.ALTERNATIVE_NO
and PRIOR A.STATE=A.STATE
)
RC on IP.Contract=RC.Contract and IP.PART_NO=RC.Root_Part_No
where IP.TYPE_CODE_DB in (&apos;1&apos;,&apos;2&apos;) and IP.PART_STATUS = &apos;A&apos; and IP.ACCOUNTING_GROUP in (&apos;MFG&apos;,&apos;COMP&apos;)
) ML on ML.Contract=CO.Contract and ML.Root_Part_No=CO.Catalog_No
Where CS.COMPANY in &apos;&amp;Company&apos; and CO.Contract like nvl (&apos;&amp;Contract&apos;,&apos;%&apos;) and CATALOG_NO like trim(nvl (&apos;&amp;Part_No&apos;,&apos;%&apos;)) and trunc(CO.REAL_SHIP_DATE) BETWEEN TO_DATE(&apos;&amp;DATE_FROM&apos;,&apos;YYYY-MM-DD&apos;) AND TO_DATE (&apos;&amp;DATE_TO&apos;,&apos;YYYY-MM-DD&apos;)
and length(CO.CUSTOMER_NO)&gt;5
) PB
inner join INVENTORY_PART IP on IP.Contract=PB.Contract and IP.Part_No=PB.CATALOG_No
inner join INVENTORY_PART IP2 on IP2.Contract=PB.Contract and IP2.Part_No=PB.Level_Part_No
OUTER APPLY (SELECT ATTR_VALUE_ALPHA FROM ifsapp.INVENTORY_PART_CHAR_ALL IPC WHERE CHARACTERISTIC_CODE=&apos;00150&apos; and IPC.Part_No= PB.CATALOG_No AND IPC.CONTRACT=PB.CONTRACT) C150
OUTER APPLY (SELECT ATTR_VALUE_ALPHA FROM ifsapp.INVENTORY_PART_CHAR_ALL IPC WHERE CHARACTERISTIC_CODE=&apos;00150&apos; and IPC.Part_No= PB.Level_Part_No AND IPC.CONTRACT=PB.CONTRACT) C150L
OUTER APPLY (SELECT ATTR_VALUE_ALPHA FROM ifsapp.INVENTORY_PART_CHAR_ALL IPC WHERE CHARACTERISTIC_CODE=&apos;00034&apos; and IPC.Part_No= PB.CATALOG_No AND IPC.CONTRACT=PB.CONTRACT) C034
OUTER APPLY (SELECT ATTR_VALUE_ALPHA FROM ifsapp.INVENTORY_PART_CHAR_ALL IPC WHERE CHARACTERISTIC_CODE=&apos;00034&apos; and IPC.Part_No= PB.Level_Part_No AND IPC.CONTRACT=PB.CONTRACT) C034L
Where
PB.Level_Part_No || &apos;-&apos; || &quot;Level&quot; not in (&apos;1005100-2&apos;,&apos;1005100-3&apos;,&apos;1005100-4&apos;)
Order BY
Contract
,REAL_SHIP_DATE
,CUSTOMER_NO
,ORDER_NO
,LINE_NO
,REL_NO
,&quot;Level&quot;</SQL_EXPRESSION>
<COMMENTS datatype="Text">This report convert the sold part into the molded part(s). You can then convert the sales into manufacturing requirements.
If the sold part is a multi component parts, then it will disaggregating it into all molded parts/components of that part.
Last level is the PART_NO of the initial manufacturing step of that sold part.
Format Date : YYYY-MM-DD
IPNA-102977
Created by: David Montminy
Date: 2024-11-29
Old HA 2025-02-23
trunc(&amp;FND_USER.VALID_FROM) and trunc(&amp;FND_USER.VALID_TO)
New HA 2025-02-23
TO_DATE(&apos;&amp;DATE_FROM&apos;,&apos;YYYY-MM-DD&apos;) AND TO_DATE (&apos;&amp;DATE_TO&apos;,&apos;YYYY-MM-DD&apos;)
2025-07-25
Updated the SQL to align with the SQL in IPL Live Environment, during IPL Cloud upgrade project</COMMENTS>
<CATEGORY_ID datatype="Number"/>
<CATEGORY_DESCRIPTION datatype="Text"/>
<DOMAIN_ID datatype="Number"/>
<DOMAIN_DESCRIPTION datatype="Text"/>
<FILE_NAME datatype="Text"/>
<QR_TYPE datatype="Enum">SQL</QR_TYPE>
<PO_ID datatype="Text"/>
<QUERY datatype="Text"/>
<ROW_TYPE datatype="Text"/>
<APP_CONFIG_PACKAGE datatype="Text"/>
<QUICK_REPORT_CATEGORY datatype="Aggregate">
<REPORT_CATEGORY state="queried">
<CATEGORY_ID datatype="Number"/>
<DESCRIPTION datatype="Text"/>
</REPORT_CATEGORY>
</QUICK_REPORT_CATEGORY>
<QUICK_REPORT_DOMAIN datatype="Aggregate">
<REPORT_DOMAIN state="queried">
<DOMAIN_ID datatype="Number"/>
<DESCRIPTION datatype="Text"/>
</REPORT_DOMAIN>
</QUICK_REPORT_DOMAIN>
</QUICK_REPORT>
</QUICK_REPORT_LIST>