I know this is nothing new but I had a hard time to find out how to get the SQL of the currently viewed Interactive Report. In one of my projects I needed the exact query including the filtered values and sorting in order to save the data into a PL/SQL collection and process it further. I tried using the existing IR Application Views but those do not provide all the information I needed. I stumbled upon this documentation page
http://docs.oracle.com/cd/E37097_01/doc/doc.42/e35127/apex_ir.htm#BABEFDJE
but was confused by the statement for getting the IR Query:
DECLARE
l_report apex_ir.t_report;
l_query varchar2(32767);
BEGIN
l_report := APEX_IR.GET_REPORT (
p_page_id => 1,
p_region_id => 2505704029884282,
p_report_id => 880629800374638220);
l_query := l_report.sql_query;
for i in 1..l_report.binds.count
loop
dbms_output.put_line(i||'. '||
l_report.binds(i).name||
'='||l_report.binds(i).value);
end loop;
END;
If you run this statement, you will receive a concatenated string of binds used in for the filtering and the corresponding values and not the actual query (it is just not printed out). In addition to that, you need to combine this statement with the one for getting the last viewed report id:
DECLARE
l_report_id number;
BEGIN
l_report_id := APEX_IR.GET_LAST_VIEWED_REPORT_ID (
p_page_id => 1,
p_region_id => 2505704029884282);
END;
After talking to
Patrick Wolf I realized that this statement delivers almost everything you need in order to get the complete query. I combined the two statements and created a function which you can use to get a query for any of your interactive reports including replaced binds. The function code is:
CREATE OR REPLACE FUNCTION get_report_sql (
p_app_id IN NUMBER,
p_page_id IN NUMBER,
p_all_cols IN BOOLEAN DEFAULT TRUE
)
RETURN VARCHAR2
IS
v_report_id NUMBER;
v_region_id NUMBER;
v_report apex_ir.t_report;
v_query VARCHAR2 (32767);
v_column VARCHAR2 (4000);
v_position NUMBER;
BEGIN
SELECT region_id
INTO v_region_id
FROM apex_application_page_regions
WHERE application_id = p_app_id
AND page_id = p_page_id
AND source_type = 'Interactive Report';
v_report_id :=
apex_ir.get_last_viewed_report_id (p_page_id => p_page_id,
p_region_id => v_region_id
);
v_report :=
apex_ir.get_report (p_page_id => p_page_id,
p_region_id => v_region_id,
p_report_id => v_report_id
);
v_query := v_report.sql_query;
FOR i IN 1 .. v_report.binds.COUNT
LOOP
v_query :=
REPLACE (v_query,
':' || v_report.binds (i).NAME,
'''' || v_report.binds (i).VALUE || ''''
);
END LOOP;
IF p_all_cols
THEN
FOR c IN (SELECT *
FROM apex_application_page_ir_col
WHERE application_id = p_app_id AND page_id = p_page_id
ORDER BY display_order)
LOOP
v_column := v_column || ', ' || c.column_alias;
END LOOP;
v_column := LTRIM (v_column, ', ');
v_position := INSTR (v_query, '(');
v_query := SUBSTR (v_query, v_position);
v_query := 'SELECT ' || v_column || ' FROM ' || v_query;
END IF;
RETURN v_query;
EXCEPTION
WHEN OTHERS
THEN
v_query := SQLERRM;
RETURN v_query;
END get_report_sql;
You can call this function in your application or in a PL/SQL package run from an application session like this:
DECLARE
v_sql VARCHAR2 (4000);
BEGIN
v_sql := get_report_sql (:app_id, :app_page_id, FALSE);
HTP.prn (v_sql);
END;
Setting the parameter
p_all_cols
to TRUE would export all columns used in the IR SQL.
Enjoy.