-
Notifications
You must be signed in to change notification settings - Fork 0
/
Sales Order Report
113 lines (103 loc) · 4.88 KB
/
Sales Order Report
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
Create and Sales Order Report based upon the following column data.
SO Report Parameters:
Warehouse (Mandatory)
Sales Order Type (Optional)
Warehouse_Org,
Order_Number,
Booked_flag,
Order_Type,
Order_Date,
Customer_Name,
Customer_Number,
Customer_PO_Number
Note:- for booked flag use 'decode' function to print Yes for Y and No for N
Generate an XML Report and based upon that, create a Business Intelligence Report.
-------------------------------------------------------------------------------------------------------------------------------------------------
## Solution
### Preparing which column has to take from which table.
SELECT * FROM OE_ORDER_HEADERS_ALL; -- BOOKED_FLAG, ORDERED_DATE, ORDER_NUMBER, END_CUSTOMER_ID
SELECT * FROM OE_ORDER_LINES_ALL; --BOOKED_FLAG, CUST_PO_NUMBER, END_CUSTOMER_ID
SELECT * FROM OE_ORDER_HOLDS_ALL;
SELECT * FROM OE_TRANSACTION_TYPES_ALL;
SELECT * FROM OE_TRANSACTION_TYPES_TL WHERE transaction_type_id = 2092;
SELECT * FROM RA_CUSTOMERS;-- CUSTOMER_ID, CUSTOMER_NAME, CUSTOMER_NUMBER, WAREHOUSE_ID,
SELECT * FROM HZ_PARTIES;
SELECT * FROM WSH_DELIVERY_DETAILS;-- CUST_PO_NUMBER, CUSTOMER_ID;
--------------------------------------------------------------------------------------------------------------------------------------------------
-- Created a procedure RD_SO with parameters ERRBUFF, RETCODE, P_WAREHOUSE_ORG, P_SALES_ORDER_TYPE.
-- Required tables are: OE_ORDER_HEADERS_ALL, HZ_PARTIES, HZ_CUST_ACCOUNTS, OE_TRANSACTION_TYPES_TL.
-- Taken OE_ORDER_HEADERS_ALL's SHIP_FROM_ORG_ID as WAREHOUSE_ORG, CUST_PO_NUMBER as CUSTOMER_PO_NUMBER & ORDERED_DATE as ORDER_DATE.
-- Taken OE_TRANSACTION_TYPES_TL's NAME as ORDER_TYPE (as instructed).
-- Taken HZ_CUST_ACCOUNTS's ACCOUNT_NUMBER as CUSTOMER_NUMBER.
-- Taken first 5 values from the tables combinations.
-- Created custom table value sets for parameters on the EBS.
Note: DECODE is the function that allows us to add procedural if-then-else logic to the query.
Here I have uses DECODE function on BOOKED_FLAG column data to print its outcome either as YES or NO instead of Y and N.
CREATE OR REPLACE PROCEDURE RD_SO(
ERRBUF OUT VARCHAR2,
RETCODE OUT NUMBER,
P_WAREHOUSE_ORG IN OE_ORDER_HEADERS_ALL.SHIP_FROM_ORG_ID%TYPE,
P_SALES_ORDER_TYPE IN OE_TRANSACTION_TYPES_TL.NAME%TYPE
)
IS
CURSOR SO_CUR
IS
SELECT DISTINCT OOHA.SHIP_FROM_ORG_ID AS WAREHOUSE_ORG,
OOHA.ORDER_NUMBER,
OTTL.NAME AS ORDER_TYPE,
OOHA.ORDERED_DATE AS ORDER_DATE,
SUBSTRB(HP_CUST.PARTY_NAME, 1,50) AS CUSTOMER_NAME,
HCA.ACCOUNT_NUMBER AS CUSTOMER_NUMBER,
OOHA.CUST_PO_NUMBER AS CUSTOMER_PO_NUMBER,
DECODE(OOHA.BOOKED_FLAG,
'Y', 'YES',
'N', 'NO',
'NULL')BOOKED_FLAG
FROM
OE_ORDER_HEADERS_ALL OOHA,
HZ_PARTIES HP_CUST,
HZ_CUST_ACCOUNTS HCA,
OE_TRANSACTION_TYPES_TL OTTL
WHERE
OOHA.SOLD_TO_ORG_ID = HCA.CUST_ACCOUNT_ID
AND OOHA.ORDER_TYPE_ID = OTTL.TRANSACTION_TYPE_ID
AND HCA.PARTY_ID = HP_CUST.PARTY_ID
AND OOHA.CUST_PO_NUMBER IS NOT NULL
AND OTTL.LANGUAGE = 'US'
AND ROWNUM < 6
AND OOHA.SHIP_FROM_ORG_ID = P_WAREHOUSE_ORG
--AND OTTL.NAME = P_SALES_ORDER_TYPE
;
SO_REC SO_CUR%ROWTYPE;
-- V_ERROR_CODE NUMBER;
--V_ERR_MESSAGE VARCHAR2(200);
BEGIN OPEN SO_CUR;
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<?xml version="1.0"?>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<SALESROOT>');
LOOP
FETCH SO_CUR INTO SO_REC;
EXIT
WHEN SO_CUR%NOTFOUND;
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<ORDER>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<WAREHOURSE_ORG>' || SO_REC.WAREHOUSE_ORG || '</WAREHOURSE_ORG>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<ORDER_NUMBER>' || SO_REC.ORDER_NUMBER || '</ORDER_NUMBER>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<ORDER_TYPE>' || SO_REC.ORDER_TYPE || '</ORDER_TYPE>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<ORDER_DATE>'|| SO_REC.ORDER_DATE || '</ORDER_DATE>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<CUSTOMER_NAME>'|| SO_REC.CUSTOMER_NAME || '</CUSTOMER_NAME>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<Customer_Number>'|| SO_REC.CUSTOMER_NUMBER || '</Customer_Number>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<Customer_Po_Number>'|| SO_REC.CUSTOMER_PO_NUMBER || '</Customer_Po_Number>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'<BOOKED_FLAG>'|| SO_REC.BOOKED_FLAG || '</BOOKED_FLAG>');
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'</ORDER>');
END LOOP;
FND_FILE.PUT_LINE(FND_FILE.OUTPUT,'</SALESROOT>');
CLOSE SO_CUR;
EXCEPTION
WHEN OTHERS THEN
FND_FILE.PUT_LINE(FND_FILE.LOG,'Error Message :' || SQLERRM);
-- V_ERROR_CODE := SQLCODE;
--
--V_ERR_MESSAGE := SUBSTR(SQLERRM,1,200);
--FND_FILE.PUT_LINE(FND_FILE.LOG, 'Error Code :' || V_ERROR_CODE);
--FND_FILE.PUT_LINE(FND_FILE.LOG,'Error Message :' || V_ERR_MESSAGE);
END;
SHOW ERROR PROCEDURE RD_SO;