A customer recently asked how APEX could track who clicked “download” from an Interactive Grid. After some quick searching of the logs, I realized that APEX simply does not record this type of activity, aside from a simple page view type of “AJAX” entry. This was not specific enough, and of course, led to the next question - can we prevent users from downloading data from a grid entirely?
I knew that any Javascript-based solution would fall short of their security requirements, since it is trivial to reconstruct the URL pattern required to initiate a download, even if the Javascript had removed the option from the menu. Thus, I had to consider a PL/SQL-based approach - one that could not be bypassed by a malicious end user.
To solve this problem, I turned to APEX’s Initialization PL/SQL Code parameter. Any PL/SQL code entered in this region will be executed before any other APEX-related process. Thus, it is literally the first place that a developer can interact with an APEX page - be it a full page view or Ajax-based process.
Both IRs and Classic Reports leave enough data in the REQUEST parameter of the URL in the logs to decode which report was downloaded and what format was selected. However, if you don’t know what the specific URL patterns look like, or don’t have the Request column selected, you’d never know it. For my solution, I chose to incorporate all three types of reports - Classic, IG and IR - which also centralized it into a single place.
The solution is relatively simple, and requires two components: a table to track the downloads and a procedure to populate the table. It should also work with both Oracle 11g & 12c. I have tested it on APEX 5.1.4. The IG portion will not work on APEX 5.0, since there is no IG component in that release.
First, create the table to store the logs:
Next, create the procedure that will capture any download.
Lastly, add a reference to the procedure to the Initialization PL/SQL Code. This can be found under your Shared Components > Security.
Once these three steps are completed, then any download of any report will be logged automatically. There’s no need to adjust any specific report or add any parameters - it will just work as reports are downloaded.
Also, uncommenting the referenced lines in each section will also prevent that kind of report from being downloaded entirely. The message could be changed as needed or even re-directed to an error page instead.
I knew that any Javascript-based solution would fall short of their security requirements, since it is trivial to reconstruct the URL pattern required to initiate a download, even if the Javascript had removed the option from the menu. Thus, I had to consider a PL/SQL-based approach - one that could not be bypassed by a malicious end user.
To solve this problem, I turned to APEX’s Initialization PL/SQL Code parameter. Any PL/SQL code entered in this region will be executed before any other APEX-related process. Thus, it is literally the first place that a developer can interact with an APEX page - be it a full page view or Ajax-based process.
Both IRs and Classic Reports leave enough data in the REQUEST parameter of the URL in the logs to decode which report was downloaded and what format was selected. However, if you don’t know what the specific URL patterns look like, or don’t have the Request column selected, you’d never know it. For my solution, I chose to incorporate all three types of reports - Classic, IG and IR - which also centralized it into a single place.
The solution is relatively simple, and requires two components: a table to track the downloads and a procedure to populate the table. It should also work with both Oracle 11g & 12c. I have tested it on APEX 5.1.4. The IG portion will not work on APEX 5.0, since there is no IG component in that release.
First, create the table to store the logs:
CREATE TABLE dl_audit_log
(
app_user VARCHAR2(255),
app_id NUMBER,
app_page_id NUMBER,
request VARCHAR2(255),
downloaded_on DATE,
report_id NUMBER,
report_name VARCHAR2(255),
report_type VARCHAR2(255),
report_format VARCHAR2(255)
)
/
Next, create the procedure that will capture any download.
CREATE OR REPLACE PROCEDURE dl_audit
(
p_request IN VARCHAR2 DEFAULT v('REQUEST'),
p_app_user IN VARCHAR2 DEFAULT v('APP_USER'),
p_app_page_id IN NUMBER DEFAULT v('APP_PAGE_ID'),
p_app_id IN NUMBER DEFAULT v('APP_ID'),
p_app_session IN NUMBER DEFAULT v('APP_SESSION')
)
AS
l_count NUMBER;
l_id NUMBER;
l_report_name VARCHAR2(255);
l_report_format VARCHAR2(255);
l_json VARCHAR2(10000);
BEGIN
-------------------------------------------------------------------------------------------------------------------------------
-- Capture Classic Report
-- Region ID will be embedded in the request
--------------------------------------------------------------------------------------------------------------------------------
CASE
WHEN p_request LIKE 'FLOW_EXCEL_OUTPUT%' THEN
-- Uncomment the two lines below to prevent the downloaded
--htp.prn('Download Prohibited');
--apex_application.g_unrecoverable_error := TRUE;
-- Get the ID
SELECT SUBSTR(p_request, 20, INSTR(p_request,'_',20)-20) INTO l_id FROM dual;
SELECT region_name INTO l_report_name FROM apex_application_page_regions WHERE region_id = l_id;
-- Log the download
INSERT INTO dl_audit_log (app_user, app_id, app_page_id, request, downloaded_on, report_id, report_name, report_type, report_format
VALUES (p_app_user, p_app_id, p_app_page_id, p_request, SYSDATE, l_id, l_report_name, 'CLASSIC', 'CSV');
-------------------------------------------------------------------------------------------------------------------------------
-- Capture IR download
-- Region ID embedded in request only when there is more than 1 IR on the page
-------------------------------------------------------------------------------------------------------------------------------
WHEN p_request LIKE '%CSV' OR p_request LIKE '%HTMLD' OR p_request LIKE '%PDF' THEN
-- Uncomment the two lines below to prevent the downloaded
--htp.prn('Download Prohibited');
--apex_application.g_unrecoverable_error := TRUE;
-- Determine how many IRs are on the page
SELECT COUNT(*) INTO l_count FROM apex_application_page_ir where page_id = p_app_page_id AND application_id = p_app_id;
-- If there is 1, then get the ID from the view
IF l_count = 1 THEN
SELECT interactive_report_id, region_name INTO l_id, l_report_name
FROM apex_application_page_ir where page_id = p_app_page_id AND application_id = p_app_id; ELSE
-- Otherwise, get the ID from the REQUEST
SELECT SUBSTR(p_request,5, INSTR(p_request,']')-5) INTO l_id FROM dual;
SELECT region_name INTO l_report_name FROM apex_application_page_ir where region_id = TRIM(l_id);
END IF;
-- Log the download
INSERT INTO dl_audit_log (app_user, app_id, app_page_id, request, downloaded_on, report_id, report_name, report_type, report_format
VALUES (p_app_user, p_app_id, p_app_page_id, p_request, SYSDATE, l_id, l_report_name, 'IR'
CASE WHEN p_request LIKE '%CSV' THEN 'CSV' WHEN p_request LIKE '%HTMLD' THEN 'HTML' WHEN p_request LIKE '%PDF' THEN 'PDF' ELSE 'OTHER' END);
-------------------------------------------------------------------------------------------------------------------------------
-- Capture IG download
--------------------------------------------------------------------------------------------------------------------------------
WHEN LOWER(owa_util.get_cgi_env('QUERY_STRING')) LIKE 'p_flow_id=' || p_app_id || '&p_flow_step_id=
|| p_app_page_id || '&p_instance=' || p_app_session || '%&p_json%download%' THEN
-- Uncomment the two lines below to prevent the downloaded
--htp.prn('Download Prohibited');
--apex_application.g_unrecoverable_error := TRUE;
-- Extract the JSON
SELECT utl_url.unescape(substr(owa_util.get_cgi_env('QUERY_STRING'),
INSTR(owa_util.get_cgi_env('QUERY_STRING'), 'p_json=') + 7)) INTO l_json FROM dual;
apex_json.parse(l_json);
-- Get the report ID
l_id := apex_json.get_varchar2(p_path => 'regions[%d].id', p0 => 1);
l_report_format := apex_json.get_varchar2(p_path => 'regions[%d].download.format', p0 => 1);
-- Lookup the name
SELECT region_name INTO l_report_name FROM apex_application_page_regions where region_id = l_id;
-- Log the download
INSERT INTO dl_audit_log (app_user, app_id, app_page_id, request, downloaded_on, report_id, report_name, report_type, report_format
VALUES (p_app_user, p_app_id, p_app_page_id, p_request, SYSDATE, l_id, l_report_name, 'GRID', l_report_format);
-- No auditing needed, as the user did not download a report
ELSE NULL;
END CASE;
END;
/
Lastly, add a reference to the procedure to the Initialization PL/SQL Code. This can be found under your Shared Components > Security.
Once these three steps are completed, then any download of any report will be logged automatically. There’s no need to adjust any specific report or add any parameters - it will just work as reports are downloaded.
Also, uncommenting the referenced lines in each section will also prevent that kind of report from being downloaded entirely. The message could be changed as needed or even re-directed to an error page instead.
Comments