CREATE OR REPLACE PACKAGE BODY EFT_NOM.geco_reporting IS
/**
#############################################################################
# #
# Package: geco_reporting #
# #
# Application System: General #
# #
# Creation Date: 29/08/2003 #
# #
# Author: Oracle Team, Advantica Ltd #
# #
# Purpose: A flexible reporting infrastructure providing output #
# in HTML #
# #
# Dependancies: Reporting Schema as defined in Designer #
# #
# Header Information: $Header: /Isle Of Grain/database/PLSQL/geco_reporting.pck 1 7/01/05 12:54 Gilberta $ #
# #
# Revision: $Revision: 1 $ #
# #
# ? Advantica Ltd, 2003 #
#############################################################################
*/
--
-- Package Variable Declaration
--
r_report_configuration report_configuration%ROWTYPE;
--
TYPE r_parameter_rec IS RECORD(
item_name VARCHAR2(2000)
,item_value VARCHAR2(2000));
--
TYPE r_parameter_tab IS TABLE OF r_parameter_rec INDEX BY BINARY_INTEGER;
--
-- Private Declaration
--
v_rownum NUMBER := 1;
--
/**
-- Procedure to retrieve the configuration record
*/
PROCEDURE get_report_configuration IS
--
--
BEGIN
--
-- Load the rowtype, limiting to one row in case more rows are entered in error
--
SELECT rcfg.*
INTO r_report_configuration
FROM report_configuration rcfg
WHERE rownum < 2;
--
END get_report_configuration;
--
/**
-- Function to determine whether a user has access to a specific report
-- @return Returns a boolean flag, TRUE meaning the user has access, FALSE meaning not
*/
FUNCTION security_check(p_rpdf_id IN report_definitions.rpdf_id%TYPE)
RETURN BOOLEAN IS
--
v_return BOOLEAN := FALSE;
--
BEGIN
--
IF p_rpdf_id IS NULL THEN
--
v_return := caco_security.security_check(g_package_name || '.startup');
--
ELSE
--
v_return := caco_security.security_check(g_package_name ||
'.startup?p_item_name_array=REPORT&p_item_value_array=' ||
p_rpdf_id);
--
END IF;
--
RETURN v_return;
--
END security_check;
--
/**
-- Procedure to update the report last run date and time
-- @param The report identifier
*/
PROCEDURE log_access(p_rpdf_id IN report_definitions.rpdf_id%TYPE) IS
--
--
BEGIN
--
-- Keep a record of when the report was last run and by whom.
--
UPDATE report_definitions rpdf
SET rpdf.last_run_date = SYSDATE
,rpdf.last_run_by = caco_utilities.get_syus_name
WHERE rpdf.rpdf_id = p_rpdf_id;
--
END log_access;
/**
-- Procedure to display the report data
-- @param The report identifier
-- @param The report type
-- @param The report parameters
-- @param The result set
*/
PROCEDURE display_report_data(p_rpdf_id IN report_definitions.rpdf_id%TYPE
,p_report_type IN report_definitions.report_type%TYPE
,p_parameter_tab IN r_parameter_tab) IS
--
v_thecursor INTEGER DEFAULT dbms_sql.open_cursor;
v_columnvalue VARCHAR2(4000);
v_status INTEGER;
v_desctbl dbms_sql.desc_tab;
v_colcnt NUMBER;
v_sql VARCHAR2(4000);
v_header_sql VARCHAR2(4000);
v_header VARCHAR2(4000);
--
v_text_delim CONSTANT VARCHAR2(1) := ',';
--
CURSOR cur_rppt(p_rpdf_id IN report_definitions.rpdf_id%TYPE, p_report_sequence IN report_parts.sequence%TYPE) IS
SELECT rppt.report_sql
,rppt.header_sql
FROM report_parts rppt
WHERE rppt.rpdf_rpdf_id = p_rpdf_id AND
rppt.sequence = p_report_sequence;
--
PROCEDURE insert_rec(p_line IN VARCHAR2) IS
BEGIN
--
INSERT INTO report_html_elements
(line
,html_row)
VALUES
(v_rownum
,p_line);
--
v_rownum := v_rownum + 1;
--
END;
--
PROCEDURE execute_immediate(p_sql IN VARCHAR2) IS
BEGIN
--
dbms_sql.parse(v_thecursor
,p_sql
,dbms_sql.native);
--
v_status := dbms_sql.EXECUTE(v_thecursor);
--
END;
--
BEGIN
--
-- Fetch the SQL corresponding to the specified report
--
OPEN cur_rppt(p_rpdf_id
,'1');
FETCH cur_rppt
INTO v_sql, v_header_sql;
CLOSE cur_rppt;
--
-- Parse the header sql
--
IF v_header_sql IS NOT NULL THEN
--
-- Check for inserts or updates
--
IF instr(upper(v_sql)
,'INSERT ') = 0 AND
instr(upper(v_sql)
,'UPDATE ') = 0 THEN
--
-- Parse the SQL
--
dbms_sql.parse(v_thecursor
,REPLACE(v_header_sql
,'`'
,'''')
,dbms_sql.native);
--
-- Bind any parameters
--
FOR i IN 1 .. p_parameter_tab.COUNT LOOP
--
-- If the bind variable is in the header
--
IF instr(lower(v_header_sql)
,lower(REPLACE(p_parameter_tab(i).item_name
,' '
,'_'))) > 0 THEN
--
-- Bind it
--
dbms_sql.bind_variable(v_thecursor
,':' || lower(REPLACE(p_parameter_tab(i)
.item_name
,' '
,'_'))
,p_parameter_tab(i).item_value);
--
END IF;
--
END LOOP;
--
dbms_sql.describe_columns(v_thecursor
,v_colcnt
,v_desctbl);
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.define_column(v_thecursor
,i
,v_header
,4000);
--
END LOOP;
--
v_status := dbms_sql.EXECUTE(v_thecursor);
--
IF dbms_sql.fetch_rows(v_thecursor) > 0 THEN
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.column_value(v_thecursor
,i
,v_header);
--
insert_rec(p_line => v_header);
--
END LOOP;
--
END IF;
--
END IF;
--
END IF;
--
IF v_sql IS NOT NULL THEN
--
--
IF p_report_type = 'PROCEDURE' THEN
dbms_sql.parse(v_thecursor
,REPLACE(v_sql
,'`'
,'''')
,dbms_sql.native);
FOR v_bind_var IN 1 .. p_parameter_tab.COUNT LOOP
dbms_sql.bind_variable(v_thecursor
,':' || lower(REPLACE(p_parameter_tab(v_bind_var)
.item_name
,' '
,'_'))
,p_parameter_tab(v_bind_var).item_value);
--
END LOOP;
v_status := dbms_sql.EXECUTE(v_thecursor);
ELSE
--
-- Check that the SQL doesn't contain any inserts or updates
--
IF instr(upper(v_sql)
,'INSERT ') > 0 OR
instr(upper(v_sql)
,'UPDATE ') > 0 THEN
--
insert_rec(p_line => htf.div(calign => 'left') ||
htf.bold('' ||
htf.italic('Error:') ||
'
' ||
'Database Inserts/Updates are not permitted.'));
--
ELSE
--
execute_immediate('alter session set nls_date_format=''DD/MM/YYYY HH24:MI'' ');
--
dbms_sql.parse(v_thecursor
,REPLACE(v_sql
,'`'
,'''')
,dbms_sql.native);
--
FOR i IN 1 .. p_parameter_tab.COUNT LOOP
--
dbms_sql.bind_variable(v_thecursor
,':' || lower(REPLACE(p_parameter_tab(i)
.item_name
,' '
,'_'))
,p_parameter_tab(i).item_value);
--
END LOOP;
--
dbms_sql.describe_columns(v_thecursor
,v_colcnt
,v_desctbl);
--
IF p_report_type IN ('HTML', 'EXCEL') THEN
--
insert_rec(p_line => htf.tableopen(cattributes => 'CLASS="tabledetail"'));
--
-- Code to repeat headers on every page
--
insert_rec(p_line => '');
--
insert_rec(p_line => htf.tablerowopen);
--
END IF;
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.define_column(v_thecursor
,i
,v_columnvalue
,4000);
--
IF p_report_type = 'HTML' THEN
--
insert_rec(p_line => htf.tabledata(cvalue => htf.bold(v_desctbl(i)
.col_name)
,cattributes => 'VALIGN = "TOP"'));
--
ELSIF p_report_type = 'EXCEL' THEN
--
insert_rec(p_line => htf.tabledata(cvalue => htf.bold(v_desctbl(i)
.col_name)));
--
END IF;
--
END LOOP;
--
IF p_report_type IN ('HTML', 'EXCEL') THEN
--
insert_rec(p_line => htf.tablerowclose);
--
-- Close the THEAD tag
--
insert_rec(p_line => '');
--
END IF;
--
v_status := dbms_sql.EXECUTE(v_thecursor);
--
IF p_report_type = 'HTML' THEN
--
WHILE (dbms_sql.fetch_rows(v_thecursor) > 0) LOOP
--
IF MOD(dbms_sql.last_row_count
,2) = 1 THEN
--
insert_rec(p_line => htf.tablerowopen(cattributes => 'CLASS="tablerowodd"'));
--
ELSE
--
insert_rec(p_line => htf.tablerowopen(cattributes => 'CLASS="tableroweven"'));
--
END IF;
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.column_value(v_thecursor
,i
,v_columnvalue);
--
insert_rec(p_line => htf.tabledata(cvalue => v_columnvalue));
--
END LOOP;
--
insert_rec(p_line => htf.tablerowclose);
--
END LOOP;
--
ELSIF p_report_type = 'EXCEL' THEN
--
WHILE (dbms_sql.fetch_rows(v_thecursor) > 0) LOOP
--
IF MOD(dbms_sql.last_row_count
,2) = 1 THEN
--
insert_rec(p_line => htf.tablerowopen(cattributes => 'CLASS="tablerowodd"'));
--
ELSE
--
insert_rec(p_line => htf.tablerowopen(cattributes => 'CLASS="tableroweven"'));
--
END IF;
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.column_value(v_thecursor
,i
,v_columnvalue);
--
insert_rec(p_line => htf.tabledata(cvalue => '="' ||
v_columnvalue || '"'));
--
END LOOP;
--
insert_rec(p_line => htf.tablerowclose);
--
END LOOP;
--
ELSIF p_report_type = 'TEXT' THEN
--
WHILE (dbms_sql.fetch_rows(v_thecursor) > 0) LOOP
--
FOR i IN 1 .. v_colcnt LOOP
--
dbms_sql.column_value(v_thecursor
,i
,v_columnvalue);
--
insert_rec(p_line => v_columnvalue || v_text_delim);
--
END LOOP;
--
insert_rec(p_line => htf.br);
--
END LOOP;
--
END IF;
--
execute_immediate('alter session set nls_date_format=''DD/MM/YYYY'' ');
--
END IF;
--
END IF;
ELSE
--
insert_rec(p_line => htf.div(calign => 'left') ||
htf.bold('' ||
htf.italic('Error:') || '
' ||
'There is a problem with this report definition.' ||
chr(10) ||
'Please contact your system administrator'));
--
END IF;
--
EXCEPTION
--
WHEN OTHERS THEN
--
execute_immediate('alter session set nls_date_format=''DD/MM/YYYY'' ');
insert_rec(p_line => htf.tableclose || htf.div(calign => 'left') ||
htf.bold('' ||
htf.italic('Error:') || '
' ||
SQLERRM));
--
END display_report_data;
--
-- Public Declaration
--
/**
-- General Date LOV procedures
*/
PROCEDURE calendar(z_field_name IN VARCHAR2
,z_caller_url IN VARCHAR2
,z_field_value IN VARCHAR2 DEFAULT NULL
,z_field_format IN VARCHAR2 DEFAULT NULL
,z_field_prompt IN VARCHAR2 DEFAULT NULL) IS
--
field_caption VARCHAR2(2000);
--
BEGIN
--
IF z_field_prompt IS NULL THEN
--
field_caption := initcap(REPLACE(substr(z_field_name
,3
,length(z_field_name) - 2)
,'_'
,' '));
--
ELSE
--
field_caption := initcap(REPLACE(z_field_prompt
,'_'
,' '));
--
END IF;
--
wsgl.registerurl(g_package_name || '.calendar');
wsgl.addurlparam('Z_FIELD_NAME'
,z_field_name);
wsgl.addurlparam('Z_CALLER_URL'
,z_caller_url);
--
IF wsgl.notlowercase THEN
RETURN;
END IF;
--
wsgl.output_calendar(z_field_name
,z_field_value
,z_field_format
,wsgl.msggettext(123
,wsglm.dsp128_cal_caption
,field_caption)
,NULL
,g_package_name
,'Close'
,TRUE
,'DD-MON-RRRR');
--
--css?
--
wsgl.output_calendar(z_field_name
,z_field_value
,z_field_format
,wsgl.msggettext(123
,wsglm.dsp128_cal_caption
,field_caption)
,NULL
,g_package_name
,'Close'
,FALSE
,'DD-MON-RRRR');
--
EXCEPTION
WHEN OTHERS THEN
wsgl.displaymessage(wsgl.mess_exception
,SQLERRM
,''
,NULL
,g_package_name || '.calendar');
END calendar;
--
PROCEDURE format_cal_date(z_field_name IN VARCHAR2
,z_field_format IN VARCHAR2
,DAY IN VARCHAR2
,MONTH IN VARCHAR2
,YEAR IN VARCHAR2) IS
--
field_caption VARCHAR2(2000) := initcap(REPLACE(substr(z_field_name
,3
,length(z_field_name) - 2)
,'_'
,' '));
l_day VARCHAR2(15) := DAY;
--
BEGIN
--
IF l_day = '0' THEN
l_day := '01';
END IF;
--
wsgl.output_format_cal_js(wsgl.msggettext(123
,wsglm.dsp128_cal_caption
,field_caption)
,NULL
,l_day || '-' || MONTH || '-' || YEAR
,z_field_format);
--
END format_cal_date;
/**
-- Function to return the list of reports defined on the system
-- @return Returns a PL/SQL table of report identifiers and names
*/
FUNCTION get_report_list RETURN g_report_tab IS
--
v_report_tab g_report_tab;
v_array_idx NUMBER;
--
BEGIN
--
/*
include check to user security
*/
FOR rpdf_rec IN (SELECT rpdf.rpdf_id AS rpdf_id
,rpdf.NAME AS NAME
FROM report_definitions rpdf
WHERE rpdf.rpdf_id IN
(SELECT substr(syop.module_name
,instr(syop.module_name
,'='
,-1) + 1)
FROM user_profiles uspr
,profile_options prop
,system_options syop
WHERE uspr.syus_id = caco_utilities.get_syus_id AND
uspr.sypr_id = prop.sypr_id AND
syop.syop_id = prop.syop_id AND
syop.module_name LIKE
g_package_name || '.startup?%')
ORDER BY rpdf.rpdf_id) LOOP
--
v_array_idx := v_report_tab.COUNT + 1;
--
v_report_tab(v_array_idx) .rpdf_id := rpdf_rec.rpdf_id;
v_report_tab(v_array_idx) .NAME := rpdf_rec.NAME;
--
END LOOP;
--
RETURN v_report_tab;
--
END get_report_list;
/**
-- Procedure to return the report list
*/
PROCEDURE get_report_list(p_index OUT g_report_list
,p_report OUT g_report_list) IS
--
v_report_tab g_report_tab;
--
BEGIN
--
v_report_tab := get_report_list;
--
IF v_report_tab.COUNT > 0 THEN
--
FOR i IN 1 .. v_report_tab.COUNT LOOP
--
p_index(i) := v_report_tab(i).rpdf_id;
p_report(i) := v_report_tab(i).NAME;
--
END LOOP;
--
END IF;
--
END get_report_list;
/**
-- Procedure to display the query screen
*/
PROCEDURE startup(p_item_name_array IN vc_arr DEFAULT g_vc_arr
,p_item_value_array IN vc_arr DEFAULT g_vc_arr) IS
--
v_report_tab g_report_tab;
--
-- Refcursor stuff
--
TYPE rc IS REF CURSOR;
v_cursor rc;
v_identifier VARCHAR2(50);
v_description VARCHAR2(50);
v_data VARCHAR2(4000);
--
v_submit_js VARCHAR2(4000);
--
BEGIN
--
-- Standard security check
--
IF (p_item_name_array.COUNT = 0 AND security_check(p_rpdf_id => NULL)) OR
(p_item_name_array.COUNT = 1 AND
security_check(p_rpdf_id => p_item_value_array(1))) THEN
--
-- Standard HTML headers
--
htp.htmlopen;
htp.headopen;
--
-- Get any style information
--
htp.linkrel('stylesheet'
,'caco_system.css?p_type=content');
--
-- Include the javascript null function
--
htp.script(cscript => 'function JSLNotNull(pctl, pmsg){ if (pctl.value == "") { alert(pmsg); pctl.focus(); return false; } return true; }');
--
htp.headclose;
--
-- Open the HTML body
--
htp.bodyopen;
--
-- Display the standard menu
--
htp.print(caco_system.menu);
--
-- Display the browser title
--
htp.title(r_report_configuration.NAME);
--
-- Display the report title
--
htp.header(nsize => 1
,cheader => r_report_configuration.NAME);
--
-- Include the calendar javascript
--
htp.p(wsgjsl.openscript);
wsgjsl.output_invoke_cal_js(g_package_name
,'scrollbars=no,resizable=no,width=320,height=350');
htp.p(wsgjsl.closescript);
--
-- Open the HTML form, calling return_results on submission
--
IF p_item_name_array.COUNT = 0 THEN
--
htp.para;
htp.p('Select a report');
htp.para;
--
htp.formopen(curl => g_package_name || '.startup'
,cmethod => 'POST'
,cattributes => 'NAME=startup');
--
ELSE
--
htp.para;
htp.p('Select the query criteria');
htp.para;
--
htp.formopen(curl => g_package_name || '.return_results'
,cmethod => 'POST'
,cattributes => 'NAME=queryscreen');
--
END IF;
--
htp.tableopen(cattributes => 'CLASS="tableheader"');
htp.tablerowopen;
htp.tabledata(cvalue => htf.bold('Report Name: ')
,cattributes => 'CLASS="tablerowheader"');
--
-- Display table data manually due to difficulties with htp.tabledata
--
htp.p('