Join the OracleApps88 Telegram group @OracleApps88to get more information on Oracle EBS R12/Oracle Fusion applications.

If you are facing any issues while copying the Code/Script or any issues with Posts, Please send a mail to OracleApp88@Yahoo.com or message me at @apps88 or +91 905 957 4321 in telegram.

Monday, June 2, 2014

Oracle Order to Cash (O2C) Life Cycle

In this article, we will go through the Order to Cash cycle. The below are the steps in short: 
1.     Enter the Sales Order
2.     Book the Sales Order
3.     Launch Pick Release
4.     Pick Confirm The Order
5.     Ship Confirm The Order
6.     Create Invoice
7.     Create the Receipts either manually or using Auto Lockbox (In this article we will concentrate on Manual creation)
8.     Transfer to General Ledger

Let’s get into the details of each step mentioned above.

1.     Enter the Sales Order:
Navigation:
Order Management Super User Operations (USA) àOrders Returns àSales Orders
 
Enter the Customer details (Ship to and Bill to address), Order type.

At this stage, the FLOW_STATUS_CODE in OE_ORDER_HEADERS_ALL is ‘Entered

SELECT
HEADER_ID
,ORDER_NUMBER
,FLOW_STATUS_CODE
,ORDER_CATEGORY_CODE
,BOOKED_FLAG
,ORG_ID
FROM oe_order_headers_all
WHERE order_number = 66465

Click on Lines Tab. Enter the Item to be ordered and the quantity required.

Line is scheduled automatically when the Line Item is saved.
Scheduling/un-scheduling can be done manually by selecting Schedule/Un schedule from the Actions Menu.

You can check if the item to be ordered is available in the Inventory by clicking on Availability Button.


Save the work.

Underlying Tables affected: 
In Oracle, Order information is maintained at the header and line level.
The header information is stored in OE_ORDER_HEADERS_ALL and the line information in OE_ORDER_LINES_ALL when the order is entered. The column called FLOW_STATUS_CODE is available in both the headers and lines tables which tell us the status of the order at each stage.

SELECT
HEADER_ID
,LINE_ID
,LINE_TYPE_ID
,FLOW_STATUS_CODE
,LINE_NUMBER
,ORDERED_ITEM
,ORDERED_QUANTITY
,UNIT_LIST_PRICE_PER_PQTY
FROM OE_ORDER_LINES_ALL
WHERE 1=1
AND HEADER_ID = 192535

  
<![if !supportLists]>2.      <![endif]>Book the Sales Order:

Book the Order by clicking on the Book Order button.

Now that the Order is BOOKED, the status on the header is change accordingly.

Underlying tables affected: 
At this stage:
The FLOW_STATUS_CODE in the table OE_ORDER_HEADERS_ALL would be
BOOKED
SELECT
HEADER_ID
,ORDER_NUMBER
,FLOW_STATUS_CODE
,ORDER_CATEGORY_CODE
,BOOKED_FLAG
,ORG_ID
FROM oe_order_headers_all
WHERE order_number = 66465

The FLOW_STATUS_CODE in OE_ORDER_LINES_ALL will be ‘AWAITING_SHIPPING’.
SELECT
HEADER_ID
,LINE_ID
,LINE_TYPE_ID
,FLOW_STATUS_CODE
,LINE_NUMBER
,ORDERED_ITEM
,ORDERED_QUANTITY
,UNIT_LIST_PRICE_PER_PQTY
FROM OE_ORDER_LINES_ALL
WHERE 1=1
AND HEADER_ID = 192535

Record(s) will be created in the table WSH_DELIVERY_DETAILS with
RELEASED_STATUS=’R’ (Ready to Release)
SELECT
DELIVERY_DETAIL_ID
,SOURCE_HEADER_ID
,SOURCE_LINE_ID
,CUSTOMER_ID
,INVENTORY_ITEM_ID
,RELEASED_STATUS
FROM WSH_DELIVERY_DETAILS
WHERE 1=1
AND SOURCE_HEADER_ID = 192535


Also Record(s) will be inserted into WSH_DELIVERY_ASSIGNMENTS.
SELECT * FROM WSH_DELIVERY_ASSIGNMENTS

At the same time DEMAND INTERFACE PROGRAM runs in the background and inserts into MTL_DEMAND 
select * from MTL_DEMAND

<![if !supportLists]>3.      <![endif]>Launch Pick Release:
Navigation:
Shipping àRelease Sales Order  àRelease Sales Orders.
 
Key in Based on Rule and Order Number

In the Shipping Tab key in the below:
Auto Create Delivery: Yes
Auto Pick Confirm: Yes
Auto Pack Delivery: Yes

In the Inventory Tab:
Auto Allocate: Yes
Enter the Warehouse : M1

Click on Execute Now Button.

On successful completion, the below message would pop up as shown below.


Pick Release process in turn will kick off several other requests like Pick Slip Report, Shipping Exception Report and Auto Pack Report

Underlying Tables affected:
If Auto create Delivery is set to ‘Yes’ then a new record is created in the table WSH_NEW_DELIVERIES.

SELECT
DELIVERY_DETAIL_ID
,SOURCE_HEADER_ID
,SOURCE_LINE_ID
,CUSTOMER_ID
,INVENTORY_ITEM_ID
,RELEASED_STATUS
FROM WSH_DELIVERY_DETAILS
WHERE 1=1
AND SOURCE_HEADER_ID = 192535

SELECT * FROM WSH_NEW_DELIVERIES
WHERE 1=1
AND DELIVERY_ID = 3773405
ORDER BY CREATION_DATE DESC

SELECT * FROM WSH_DELIVERY_ASSIGNMENTS
WHERE 1=1
AND DELIVERY_DETAIL_ID = 3962503
ORDER BY CREATION_DATE DESC

DELIVERY_ID is populated in the table WSH_DELIVERY_ASSIGNMENTS.
The RELEASED_STATUS in WSH_DELIVERY_DETAILS would be now set to ‘Y’ (Pick Confirmed) if Auto Pick Confirm is set to Yes otherwise RELEASED_STATUS is ‘S’ (Release to Warehouse).


<![if !supportLists]>4.      <![endif]>Pick Confirm the Order:
IF Auto Pick Confirm in the above step is set to NO, then the following should be done.
Navigation:
Inventory Super User > Move Order> Transact Move Order
 

In the HEADER tab, enter the BATCH NUMBER (from the above step) of the order. Click FIND. Click on VIEW/UPDATE Allocation, then Click TRANSACT button. Then Transact button will be deactivated then just close it and go to next step.

<![if !supportLists]>5.      <![endif]>Ship Confirm the Order:
Navigation:
Order Management Super User>Shipping >Transactions.
 

Query with the Order Number.
  
Click On Delivery Tab

Click on Ship Confirm.
 

 


The Status in Shipping Transaction screen will now be closed.

This will kick off concurrent programs like. INTERFACE TRIP Stop, Commercial Invoice, Packing Slip Report, Bill of Lading

Underlying tables affected:

RELEASED_STATUS in WSH_DELIVERY_DETAILS would be ‘C’ (Ship Confirmed)
FLOW_STATUS_CODE in OE_ORDER_HEADERS_ALL would be “BOOKED“
FLOW_STATUS_CODE in OE_ORDER_LINES_ALL would be “SHIPPED“

SELECT
HEADER_ID
,ORDER_NUMBER
,FLOW_STATUS_CODE
,ORDER_CATEGORY_CODE
,BOOKED_FLAG
,ORG_ID
FROM oe_order_headers_all
WHERE order_number = 66435

SELECT
HEADER_ID
,LINE_ID
,LINE_TYPE_ID
,FLOW_STATUS_CODE
,LINE_NUMBER
,ORDERED_ITEM
,ORDERED_QUANTITY
,UNIT_LIST_PRICE_PER_PQTY
FROM OE_ORDER_LINES_ALL
WHERE 1=1
AND HEADER_ID = 192535

SELECT
DELIVERY_DETAIL_ID
,SOURCE_HEADER_ID
,SOURCE_LINE_ID
,CUSTOMER_ID
,INVENTORY_ITEM_ID
,RELEASED_STATUS
FROM WSH_DELIVERY_DETAILS
WHERE 1=1
AND SOURCE_HEADER_ID = 192535


<![if !supportLists]>6.      <![endif]>Create Invoice:

Run workflow background Process.

Navigation:
Order Management >view >Requests
  
Workflow Background Process inserts the records RA_INTERFACE_LINES_ALL with

INTERFACE_LINE_CONTEXT     =     ’ORDER ENTRY’
INTERFACE_LINE_ATTRIBUTE1=     Order_number
INTERFACE_LINE_ATTRIBUTE3=     Delivery_id

SELECT * FROM RA_INTERFACE_LINES_ALL
WHERE 1=1
AND INTERFACE_LINE_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_LINE_ATTRIBUTE1 = 66435
AND INTERFACE_LINE_ATTRIBUTE3 = 3773405

and spawns Auto invoice Master Program and Auto invoice import program which creates Invoice for that particular Order.

Check the invoice details from order form query with order number click on Actions and select Additional Order Information

Click on Invoice/Credit memo tab

The Invoice created can be seen using the Receivables responsibility

Navigation:
Receivables Super User> Transactions> Transactions

Query with the Order Number as Reference.
  


Underlying tables:
RA_CUSTOMER_TRX_ALL will have the Invoice header information. The column INTERFACE_HEADER_ATTRIBUTE1 will have the Order Number.

RA_CUSTOMER_TRX_LINES_ALL will have the Invoice lines information. The column INTERFACE_LINE_ATTRIBUTE1 will have the Order Number.

SELECT
CUSTOMER_TRX_ID
,TRX_NUMBER
,INTERFACE_HEADER_ATTRIBUTE1
,INTERFACE_HEADER_ATTRIBUTE2
,INTERFACE_HEADER_ATTRIBUTE3
,INTERFACE_HEADER_CONTEXT
,STATUS_TRX
FROM RA_CUSTOMER_TRX_ALL
WHERE 1=1
AND INTERFACE_HEADER_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_HEADER_ATTRIBUTE1 = '66435'
AND INTERFACE_HEADER_ATTRIBUTE3 = 3773405
ORDER BY CREATION_DATE DESC

SELECT * FROM RA_CUSTOMER_TRX_LINES_ALL
WHERE 1=1
AND TRX_NUMBER = ’10037546’
AND INTERFACE_LINE_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_LINE_ATTRIBUTE1 = 66435
AND INTERFACE_LINE_ATTRIBUTE3 = 3773405
ORDER BY CREATION_DATE DESC

<![if !supportLists]>7.      <![endif]>Create receipt:
Navigation:
Receivables> Receipts> Receipts

Enter the information.

Click on Apply Button to apply it to the Invoice.

Save the form

Underlying tables:
SELECT * FROM AR_CASH_RECEIPTS_ALL
WHERE 1=1
AND RECEIPT_NUMBER = 'R10037546'
ORDER BY CREATION_DATE DESC

SELECT * FROM AR_RECEIVABLE_APPLICATIONS_ALL
WHERE 1=1
AND CASH_RECEIPT_ID = 113993
ORDER BY CREATION_DATE DESC

SELECT * FROM AR_PAYMENT_SCHEDULES_ALL
WHERE 1=1
AND CASH_RECEIPT_ID = 113993
ORDER BY CREATION_DATE DESC

Check the invoice balance amount from invoice transaction form

  

Create receipt for balance amount


<![if !supportLists]>8        <![endif]>Transfer to General Ledger:





Go to General Ledger and check the account





SELECT
HEADER_ID
,ORDER_NUMBER
,FLOW_STATUS_CODE
,ORDER_CATEGORY_CODE
,BOOKED_FLAG
,ORG_ID
FROM oe_order_headers_all
WHERE order_number = 66435

SELECT
HEADER_ID
,LINE_ID
,LINE_TYPE_ID
,FLOW_STATUS_CODE
,LINE_NUMBER
,ORDERED_ITEM
,ORDERED_QUANTITY
,UNIT_LIST_PRICE_PER_PQTY
FROM OE_ORDER_LINES_ALL
WHERE 1=1
AND HEADER_ID = 192535

SELECT
DELIVERY_DETAIL_ID
,SOURCE_HEADER_ID
,SOURCE_LINE_ID
,CUSTOMER_ID
,INVENTORY_ITEM_ID
,RELEASED_STATUS
FROM WSH_DELIVERY_DETAILS
WHERE 1=1
AND SOURCE_HEADER_ID = 192535


SELECT * FROM WSH_NEW_DELIVERIES
WHERE 1=1
AND DELIVERY_ID = 3773405
ORDER BY CREATION_DATE DESC

SELECT * FROM WSH_DELIVERY_ASSIGNMENTS
WHERE 1=1
AND DELIVERY_DETAIL_ID = 3962503
ORDER BY CREATION_DATE DESC

SELECT * FROM RA_INTERFACE_LINES_ALL
WHERE 1=1
AND INTERFACE_LINE_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_LINE_ATTRIBUTE1 = 66435
AND INTERFACE_LINE_ATTRIBUTE3 = 3773405

SELECT
CUSTOMER_TRX_ID
,TRX_NUMBER
,INTERFACE_HEADER_ATTRIBUTE1
,INTERFACE_HEADER_ATTRIBUTE2
,INTERFACE_HEADER_ATTRIBUTE3
,INTERFACE_HEADER_CONTEXT
,STATUS_TRX
FROM RA_CUSTOMER_TRX_ALL
WHERE 1=1
AND INTERFACE_HEADER_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_HEADER_ATTRIBUTE1 = '66435'
AND INTERFACE_HEADER_ATTRIBUTE3 = 3773405
ORDER BY CREATION_DATE DESC

SELECT * FROM RA_CUSTOMER_TRX_LINES_ALL
WHERE 1=1
AND INTERFACE_LINE_CONTEXT = 'ORDER ENTRY'
AND INTERFACE_LINE_ATTRIBUTE1 = 66435
AND INTERFACE_LINE_ATTRIBUTE3 = 3773405
ORDER BY CREATION_DATE DESC


SELECT * FROM AR_CASH_RECEIPTS_ALL
WHERE 1=1
AND RECEIPT_NUMBER = 'R10037546'
ORDER BY CREATION_DATE DESC

SELECT * FROM AR_RECEIVABLE_APPLICATIONS_ALL
WHERE 1=1
AND CASH_RECEIPT_ID = 113993
ORDER BY CREATION_DATE DESC

SELECT * FROM AR_PAYMENT_SCHEDULES_ALL
WHERE 1=1
AND CASH_RECEIPT_ID = 113993
ORDER BY CREATION_DATE DESC


**************** O2C Complete Query ****************

select ooha.order_number,ooha.org_id,
       hca.account_name,
       hp.party_name "Customer Name",
       hcasab.orig_system_reference      BILL_TO_ORIG_REF,
       hpsb.status                       BILL_TO_STATUS,
       'ADDRESS1 - '||bill_loc.address1||','||CHR(10)|| 'ADDRESS2 - '||bill_loc.address2||','||CHR(10)||
       'ADDRESS3 - '||bill_loc.address3||','||CHR(10)|| 'CITY     - '||bill_loc.city||','||CHR(10)||
       'POSTAL CD- '||bill_loc.postal_code||','||CHR(10)|| 'COUNTRY  - '|| bill_loc.country  BILL_TO_ADDRESS,
       hcasas.orig_system_reference      SHIP_TO_ORIG_REF,
       hpss.status SHIP_TO_STATUS,
       'ADDRESS1 - '||ship_loc.address1||','||CHR(10)|| 'ADDRESS2 - '||ship_loc.address2||','||CHR(10)||
       'ADDRESS3 - '||ship_loc.address3||','||CHR(10)|| 'CITY     - '||ship_loc.city||','||CHR(10)||
       'POSTAL CD- '||ship_loc.postal_code||','||CHR(10)|| 'COUNTRY  - '|| ship_loc.country  SHIP_TO_ADDRESS,
       oola.inventory_item_id,oola.ordered_item,
       msib.description item_description,
       wnd.name delivery_number,
       rct.trx_number "AR Invoice Number",
       acr.receipt_number "AR Receipt Number",
       gjh.ledger_id,
       gjh.name
  from oe_order_headers_all ooha,
       oe_order_lines_all oola,
       hz_parties hp,
       hz_cust_accounts hca,
       hz_party_sites hpss,
       hz_party_sites hpsb,
       hz_locations bill_loc,
       hz_locations ship_loc,
       hz_cust_acct_sites_all hcasab,
       hz_cust_acct_sites_all hcasas,
       hz_cust_site_uses_all hzsuab,
       hz_cust_site_uses_all hzsuas,
       mtl_system_items_b msib,
       wsh_delivery_details wdd,
       wsh_new_deliveries wnd,
       wsh_delivery_assignments wda,
       ra_customer_trx_all rct,
       ra_customer_trx_lines_all rctl,
       ra_cust_trx_line_gl_dist_all rctld,      
       ar_cash_receipts_all acr,
       xla.xla_transaction_entities xte,
       xla_events xe,
       xla_ae_headers xah,
       xla_ae_lines xal,
       xla_distribution_links xdl,
       gl_import_references gir,
       gl_je_batches gjb,
       gl_je_headers gjh,
       gl_je_lines gjl
where ooha.order_number = :SalesOrderNumber --Right click :RequitionNumber from Toad Enable Prompt For Substitution Variables
   and ooha.org_id = 204
   and hca.cust_account_id    = ooha.sold_to_org_id
   and hp.party_id            = hca.party_id
   and hpss.party_id            = hca.party_id
   and hpsb.party_id            = hca.party_id
   and bill_loc.location_id = hpss.location_id
   and ship_loc.location_id = hpsb.location_id
   AND hcasas.cust_account_id  = hca.cust_account_id
   AND hcasab.cust_account_id  = hca.cust_account_id
   AND hcasas.party_site_id    = hpss.party_site_id
   AND hcasab.party_site_id    = hpsb.party_site_id
   and hzsuas.cust_acct_site_id = hcasas.cust_acct_site_id
   and hzsuab.cust_acct_site_id = hcasab.cust_acct_site_id
   and hzsuas.site_use_id = ooha.ship_to_org_id
   and hzsuab.site_use_id = ooha.invoice_to_org_id          
   and wda.delivery_id        = wnd.delivery_id(+)
   and wdd.delivery_detail_id = wda.delivery_detail_id
   and wdd.source_header_id   = ooha.header_id
   and wdd.source_line_id     = oola.line_id
   and wdd.organization_id    = msib.organization_id(+)
   and wdd.inventory_item_id  =msib.inventory_item_id(+)
   and rct.interface_header_attribute1 = to_char(ooha.order_number)
   and rct.org_id = ooha.org_id
   and rctl.customer_trx_id = rct.customer_trx_id
   and rctl.sales_order = to_char(ooha.order_number)
   and rctld.customer_trx_id = rct.customer_trx_id
   and rctld.customer_trx_line_id = rctl.customer_trx_line_id
   and acr.receipt_number = 'G-1001'
   and acr.pay_from_customer = rct.sold_to_customer_id
   and acr.org_id = ooha.org_id
   and acr.customer_site_use_id = rct.bill_to_site_use_id
   and xte.transaction_number = acr.receipt_number
   and xte.entity_code = 'RECEIPTS'
   and xe.entity_id = xte.entity_id
   and xah.event_id = xe.event_id
   and xal.ae_header_id = xah.ae_header_id
   and xal.accounting_class_code = 'CASH'
   and xdl.ae_header_id = xah.ae_header_id
   and xdl.ae_line_num = xal.ae_line_num
   --and xdl.source_distribution_id_num_1
   and gir.reference_5 = xte.entity_id  -- Entity Id
   and gir.reference_6 = to_char(xe.event_id) --Event Id
   and gir.reference_7 = to_char (xah.ae_header_id) -- AE Header Id
   and gir.gl_sl_link_id = xal.gl_sl_link_id
   and gir.created_by = 1318
   and gjb.je_batch_id = gir.je_batch_id
   and gjh.je_batch_id=gjb.je_batch_id
   and gjh.je_header_id = gir.je_header_id
   and gjl.je_header_id=gjh.je_header_id
   and gjl.je_line_num= gir.je_line_num

14 comments:

Elu said...

Thank you so much for sharing Raju...

Very good thread about O2C and its underlying tables.

Anonymous said...

Good One Raju .. Where does collections fit in O2C Cycle?

rajeswari said...

Good to see this from you

Regards,
Rajeswari

rajeswari said...

Good one Raju,Thanks for Sharing :)

Unknown said...

It's help a lot

Unknown said...

It's help a lot

Unknown said...

Superb Raju

Sravanthi Pentyala said...

Good Raju

Dorian said...

Qué berraquera!!! = What a wonderful!!!

Unknown said...

Good Job!!!

Anonymous said...

Excellent Job Sir !

Narayana Murthy Kayala said...

Very Good Blog Raju .. Both Functionally and Technically well explained

Subh said...

Really i appreciate your effort.
Welldone Bro..

Anonymous said...

Super

Post a Comment

If you are facing any issues while copying the Code/Script or any issues with Posts, Please send a mail to OracleApp88@Yahoo.com or message me at @apps88 or +91 905 957 4321 in telegram.
Best Blogger TipsGet Flower Effect