1311 lines
46 KiB
Plaintext
1311 lines
46 KiB
Plaintext
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('<font color="ff4040" size=+2>' ||
|
|
htf.italic('Error:') ||
|
|
'</font><BR>' ||
|
|
'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 => '<THEAD style="display:table-header-group;">');
|
|
--
|
|
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 => '</THEAD>');
|
|
--
|
|
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('<font color="ff4040" size=+2>' ||
|
|
htf.italic('Error:') || '</font><BR>' ||
|
|
'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('<font color="ff4040" size=+2>' ||
|
|
htf.italic('Error:') || '</font><BR>' ||
|
|
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('<TD CLASS="tablerowheader">');
|
|
--
|
|
htp.formhidden(cname => 'p_item_name_array'
|
|
,cvalue => 'REPORT');
|
|
--
|
|
IF p_item_name_array.COUNT = 0 THEN
|
|
--
|
|
htp.formselectopen(cname => 'p_item_value_array'
|
|
,cattributes => 'onchange="javascript:{this.form.submit();}"');
|
|
--
|
|
-- Display the default 'Select a Report:' caption if we haven't selected a report
|
|
--
|
|
htp.formselectoption(cvalue => 'Select a report:'
|
|
,cattributes => 'VALUE="0"');
|
|
--
|
|
ELSE
|
|
--
|
|
htp.formselectopen(cname => 'p_item_value_array'
|
|
,cattributes => 'READONLY');
|
|
--
|
|
END IF;
|
|
--
|
|
-- Get the list of reports applicable to this user and display in a poplist
|
|
--
|
|
v_report_tab := get_report_list;
|
|
--
|
|
IF v_report_tab.COUNT > 0 THEN
|
|
--
|
|
FOR i IN 1 .. v_report_tab.COUNT LOOP
|
|
--
|
|
IF p_item_name_array.COUNT > 0 THEN
|
|
--
|
|
IF v_report_tab(i).rpdf_id = p_item_value_array(1) THEN
|
|
--
|
|
htp.formselectoption(cvalue => v_report_tab(i).NAME
|
|
,cattributes => 'VALUE="' ||
|
|
v_report_tab(i)
|
|
.rpdf_id || '"'
|
|
,cselected => 'YES');
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
htp.formselectoption(cvalue => v_report_tab(i).NAME
|
|
,cattributes => 'VALUE="' ||
|
|
v_report_tab(i)
|
|
.rpdf_id || '"');
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
htp.formselectclose;
|
|
htp.p('</TD>');
|
|
htp.tablerowclose;
|
|
--
|
|
IF (p_item_name_array.COUNT > 0 AND p_item_value_array(1) <> '0') THEN
|
|
--
|
|
FOR cur_rppp IN (SELECT rppp.NAME
|
|
,decode(rppp.mandatory
|
|
,'N'
|
|
,rppp.title
|
|
,rppp.title || '(*)') AS title
|
|
,rppp.TYPE
|
|
,rppp.data
|
|
,(rppp.rppp_seq * 2) + 1 AS rppp_seq
|
|
,rppp.mandatory
|
|
FROM report_part_params rppp
|
|
WHERE rppp.rppt_id = p_item_value_array(1)
|
|
ORDER BY rppp_seq) LOOP
|
|
--
|
|
IF cur_rppp.mandatory = 'Y' THEN
|
|
--
|
|
v_submit_js := v_submit_js || 'if (!JSLNotNull(elements[' ||
|
|
cur_rppp.rppp_seq || '], ''' ||
|
|
substr(cur_rppp.title
|
|
,1
|
|
,length(cur_rppp.title) - 3) ||
|
|
': A value must be entered'')) {elements[' ||
|
|
cur_rppp.rppp_seq || '].focus(); return false }' ||
|
|
chr(10);
|
|
--
|
|
END IF;
|
|
--
|
|
htp.formhidden(cname => 'p_item_name_array'
|
|
,cvalue => cur_rppp.NAME);
|
|
htp.tablerowopen;
|
|
--
|
|
IF cur_rppp.TYPE = 'CHAR' THEN
|
|
--
|
|
htp.tabledata(cvalue => htf.bold(cur_rppp.title || ': ')
|
|
,cattributes => 'CLASS="tablerowheader"');
|
|
htp.tabledata(cvalue => htf.formtext('p_item_value_array'
|
|
,16
|
|
,16
|
|
,NULL)
|
|
,cattributes => 'CLASS="tablerowheader"');
|
|
--
|
|
ELSIF cur_rppp.TYPE = 'DATE' THEN
|
|
--
|
|
htp.tabledata(cvalue => htf.bold(cur_rppp.title || ': ')
|
|
,cattributes => 'CLASS="tablerowheader"');
|
|
htp.tabledata(cvalue => htf.formtext('p_item_value_array'
|
|
,16
|
|
,16
|
|
,NULL) ||
|
|
wsgjsl.calbutton(field_name => 'elements[' ||
|
|
cur_rppp.rppp_seq || ']'
|
|
,p_calbut => htf.img(curl => caco_system.images_path||'lov.gif'
|
|
,calign => 'TOP'
|
|
,cattributes => 'ALT="List Values" WIDTH=18 HEIGHT=22 BORDER')
|
|
,field_format => 'DD-MON-YYYY'
|
|
,p_field_prompt => cur_rppp.title));
|
|
--
|
|
ELSIF cur_rppp.TYPE = 'STATICPOP' THEN
|
|
--
|
|
-- Expecting a list of id:descr; e.g. 1:Blue;2:Red;
|
|
--
|
|
htp.tabledata(cvalue => htf.bold(cur_rppp.title || ': ')
|
|
,cattributes => 'CLASS="tablerowheader"');
|
|
htp.p('<TD CLASS="tablerowheader">');
|
|
htp.formselectopen(cname => 'p_item_value_array');
|
|
--
|
|
v_data := cur_rppp.data;
|
|
--
|
|
FOR i IN 1 .. length(v_data) -
|
|
length(REPLACE(v_data
|
|
,';')) LOOP
|
|
--
|
|
htp.formselectoption(cvalue => substr(v_data
|
|
,instr(v_data
|
|
,':') + 1
|
|
,instr(v_data
|
|
,';') -
|
|
instr(v_data
|
|
,':') - 1)
|
|
,cattributes => 'VALUE="' ||
|
|
substr(v_data
|
|
,1
|
|
,instr(v_data
|
|
,':') - 1) || '"');
|
|
--
|
|
v_data := substr(v_data
|
|
,instr(v_data
|
|
,';') + 1);
|
|
--
|
|
END LOOP;
|
|
--
|
|
htp.formselectclose;
|
|
htp.p('</TD>');
|
|
--
|
|
ELSIF cur_rppp.TYPE = 'SQLPOP' THEN
|
|
--
|
|
htp.tabledata(cvalue => htf.bold(cur_rppp.title || ': ')
|
|
,cattributes => 'CLASS="tablerowheader"');
|
|
htp.p('<TD CLASS="tablerowheader">');
|
|
htp.formselectopen(cname => 'p_item_value_array');
|
|
--
|
|
IF cur_rppp.mandatory = 'N' THEN
|
|
--
|
|
htp.formselectoption(cvalue => ''
|
|
,cattributes => '');
|
|
--
|
|
END IF;
|
|
--
|
|
OPEN v_cursor FOR cur_rppp.data;
|
|
LOOP
|
|
--
|
|
FETCH v_cursor
|
|
INTO v_identifier, v_description;
|
|
EXIT WHEN v_cursor%NOTFOUND;
|
|
--
|
|
htp.formselectoption(cvalue => v_description
|
|
,cattributes => 'VALUE="' || v_identifier || '"');
|
|
--
|
|
END LOOP;
|
|
--
|
|
CLOSE v_cursor;
|
|
--
|
|
htp.formselectclose;
|
|
htp.p('</TD>');
|
|
--
|
|
END IF;
|
|
--
|
|
htp.tablerowclose;
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
htp.tableclose;
|
|
--
|
|
IF p_item_name_array.COUNT > 0 THEN
|
|
--
|
|
htp.br;
|
|
htp.formhidden(cname => 'p_item_name_array'
|
|
,cvalue => 'BUTTON');
|
|
--
|
|
-- Check to see if we should include mandatory parameter javascript
|
|
--
|
|
IF v_submit_js IS NOT NULL THEN
|
|
--
|
|
htp.formsubmit(cname => 'p_item_value_array'
|
|
,cvalue => 'Run Report'
|
|
,cattributes => 'onclick="' || v_submit_js ||
|
|
' return true;"');
|
|
--
|
|
ELSE
|
|
--
|
|
htp.formsubmit(cname => 'p_item_value_array'
|
|
,cvalue => 'Run Report');
|
|
--
|
|
END IF;
|
|
--
|
|
htp.formsubmit(cname => 'p_item_value_array'
|
|
,cvalue => 'Cancel');
|
|
--
|
|
END IF;
|
|
--
|
|
htp.formclose;
|
|
--
|
|
htp.bodyclose;
|
|
htp.htmlclose;
|
|
--
|
|
END IF;
|
|
--
|
|
END startup;
|
|
/**
|
|
-- Function to return the results of the selected report
|
|
-- @param x
|
|
-- @return Returns a PL/SQL table of the report results
|
|
*/
|
|
FUNCTION return_results(p_item_name_array IN vc_arr
|
|
,p_item_value_array IN vc_arr) RETURN VARCHAR2 IS
|
|
--
|
|
-- Local variable declaration
|
|
--
|
|
v_rpdf_id report_definitions.rpdf_id%TYPE;
|
|
v_button_action VARCHAR2(30);
|
|
v_report_title report_definitions.display_title%TYPE;
|
|
v_report_type report_definitions.report_type%TYPE;
|
|
v_show_header report_definitions.show_header%TYPE;
|
|
--
|
|
-- Result set array
|
|
--
|
|
v_return VARCHAR2(1);
|
|
v_parameter_tab r_parameter_tab;
|
|
--
|
|
-- Procedure to add output to the array
|
|
--
|
|
PROCEDURE store_line(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 store_line;
|
|
--
|
|
FUNCTION scan_array(p_item_name_array IN vc_arr
|
|
,p_item_value_array IN vc_arr
|
|
,p_parameter_tab IN OUT r_parameter_tab
|
|
,p_rpdf_id IN OUT report_definitions.rpdf_id%TYPE
|
|
,p_button_action IN OUT VARCHAR2) RETURN BOOLEAN IS
|
|
--
|
|
v_return BOOLEAN := FALSE;
|
|
v_array_idx NUMBER := 1;
|
|
--
|
|
BEGIN
|
|
--
|
|
FOR i IN 1 .. p_item_name_array.COUNT LOOP
|
|
--
|
|
IF p_item_name_array(i) = 'REPORT' THEN
|
|
--
|
|
p_rpdf_id := p_item_value_array(i);
|
|
--
|
|
ELSIF p_item_name_array(i) = 'BUTTON' THEN
|
|
--
|
|
p_button_action := p_item_value_array(i);
|
|
--
|
|
ELSE
|
|
--
|
|
p_parameter_tab(v_array_idx) .item_name := p_item_name_array(i);
|
|
p_parameter_tab(v_array_idx) .item_value := p_item_value_array(i);
|
|
v_array_idx := v_array_idx + 1;
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP;
|
|
--
|
|
IF p_rpdf_id IS NOT NULL AND p_button_action IS NOT NULL THEN
|
|
--
|
|
v_return := TRUE;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN v_return;
|
|
--
|
|
END scan_array;
|
|
--
|
|
BEGIN
|
|
--
|
|
-- Scan the passed array getting details about the report, if passed
|
|
--
|
|
IF scan_array(p_item_name_array
|
|
,p_item_value_array
|
|
,v_parameter_tab
|
|
,v_rpdf_id
|
|
,v_button_action) THEN
|
|
--
|
|
-- Mandatory parameters passed, continue processing the requested action
|
|
--
|
|
IF v_button_action = 'Run Report' THEN
|
|
--
|
|
-- Perform a security check to ensure that the specified user can view this report
|
|
--
|
|
IF security_check(v_rpdf_id) THEN
|
|
--
|
|
-- Log access to this report
|
|
--
|
|
log_access(p_rpdf_id => v_rpdf_id);
|
|
--
|
|
-- Fetch the report title
|
|
--
|
|
SELECT rpdf.display_title
|
|
,rpdf.report_type
|
|
,rpdf.show_header
|
|
INTO v_report_title
|
|
,v_report_type
|
|
,v_show_header
|
|
FROM report_definitions rpdf
|
|
WHERE rpdf.rpdf_id = v_rpdf_id;
|
|
--
|
|
IF v_report_type = 'HTML' THEN
|
|
--
|
|
--
|
|
-- Initialise the HTML page
|
|
--
|
|
store_line(htf.htmlopen);
|
|
store_line(htf.headopen);
|
|
--
|
|
-- Get any style information
|
|
--
|
|
store_line(htf.linkrel('stylesheet'
|
|
,'caco_system.css?p_type=content'));
|
|
--
|
|
store_line(htf.headclose);
|
|
--
|
|
-- Open the HTML body
|
|
--
|
|
store_line(htf.bodyopen);
|
|
--
|
|
-- Display the standard menu
|
|
--
|
|
-- FOR i IN 1 .. ceil(length(caco_system.menu) / 972) LOOP
|
|
--
|
|
-- store_line(substr(caco_system.menu
|
|
-- ,((i * 972) - 971)
|
|
-- ,972));
|
|
-- --
|
|
-- END LOOP;
|
|
store_line(caco_system.menu);
|
|
--
|
|
--
|
|
-- Display the browser title
|
|
--
|
|
store_line(htf.title(r_report_configuration.NAME));
|
|
--
|
|
-- Run the debug procedure if configured
|
|
--
|
|
IF r_report_configuration.debug = 'Y' THEN
|
|
--
|
|
-- Store all passed parameter
|
|
--
|
|
store_line(htf.br);
|
|
--
|
|
FOR i IN 1 .. p_item_name_array.COUNT LOOP
|
|
--
|
|
store_line('Name: ' || p_item_name_array(i) ||
|
|
htf.bold(' Value: ' || p_item_value_array(i)));
|
|
store_line(htf.br);
|
|
--
|
|
END LOOP;
|
|
--
|
|
store_line(htf.br);
|
|
--
|
|
END IF;
|
|
--
|
|
-- Display the report title
|
|
--
|
|
store_line(htf.header(nsize => 1
|
|
,calign => 'CENTER'
|
|
,cattributes => 'style="TEXT-ALIGN: center"'
|
|
,cheader => v_report_title));
|
|
--
|
|
store_line(htf.para);
|
|
--
|
|
-- Display the report header if selected
|
|
--
|
|
IF v_show_header = 'Y' THEN
|
|
--
|
|
store_line(htf.div(calign => 'center'));
|
|
store_line(htf.tableopen(cattributes => 'CLASS="tableheader"'));
|
|
--
|
|
store_line(htf.tablerowopen);
|
|
store_line(htf.tabledata(cvalue => 'Username:'
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tabledata(cvalue => USER
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tabledata(cvalue => 'Report Run Time:'
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tabledata(cvalue => to_char(SYSDATE
|
|
,'HH24:MI DD Month YYYY')
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tablerowclose);
|
|
--
|
|
FOR i IN 1 .. v_parameter_tab.COUNT LOOP
|
|
--
|
|
store_line(htf.tablerowopen);
|
|
--
|
|
IF i = v_parameter_tab.FIRST THEN
|
|
--
|
|
-- First entry, display the title
|
|
--
|
|
store_line(htf.tabledata(cvalue => 'Report Parameters:'
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
--
|
|
ELSE
|
|
--
|
|
-- Subsequent entry, display an empty cell
|
|
--
|
|
store_line(htf.tabledata(cvalue => ''
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
--
|
|
END IF;
|
|
--
|
|
store_line(htf.tabledata(cvalue => ''
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tabledata(cvalue => initcap(v_parameter_tab(i)
|
|
.item_name) || ':'
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tabledata(cvalue => v_parameter_tab(i)
|
|
.item_value
|
|
,cattributes => 'CLASS="tablerowheader"'));
|
|
store_line(htf.tablerowclose);
|
|
--
|
|
END LOOP;
|
|
--
|
|
-- Close the table
|
|
--
|
|
store_line(htf.tableclose);
|
|
--
|
|
store_line(htf.para);
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF v_report_type = 'EXCEL' THEN
|
|
--
|
|
IF v_show_header = 'Y' THEN
|
|
--
|
|
store_line(htf.header(nsize => 1
|
|
,calign => 'LEFT'
|
|
,cattributes => 'style="TEXT-ALIGN: left"'
|
|
,cheader => v_report_title));
|
|
--
|
|
store_line(htf.para);
|
|
--
|
|
END IF;
|
|
--
|
|
owa_util.mime_header(ccontent_type => 'application/vnd.ms-excel');
|
|
--
|
|
END IF;
|
|
--
|
|
-- Display the actual data
|
|
--
|
|
display_report_data(v_rpdf_id
|
|
,v_report_type
|
|
,v_parameter_tab);
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
-- Other button action, will assume it is cancel
|
|
--
|
|
store_line(htf.script(cscript => '<!-- Begin
|
|
redirTime = "5000";
|
|
redirURL = "' ||
|
|
(lower(owa_util.get_cgi_env('REQUEST_PROTOCOL') ||
|
|
'://' ||
|
|
owa_util.get_cgi_env('HTTP_HOST') ||
|
|
'/pls/' ||
|
|
owa_util.get_cgi_env(param_name => 'DAD_NAME') || '/')) ||
|
|
g_package_name ||
|
|
'.startup";
|
|
function queryredirect() { self.setTimeout("self.location.href = redirURL;",redirTime); }
|
|
// End --> '));
|
|
store_line(htf.bodyopen(cattributes => 'onLoad="queryredirect()"'));
|
|
store_line(htf.bold('<font color="green" size=+2>' ||
|
|
htf.italic('Information:') || '</font><BR>' ||
|
|
'Report cancelled at users request. You will now be redirected to the main page.'));
|
|
store_line(htf.bodyclose);
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
-- Missing parameters
|
|
--
|
|
store_line(htf.bold('<font color="ff4040" size=+2>' ||
|
|
htf.italic('Error:') || '</font><BR>' ||
|
|
'Missing mandatory parameter'));
|
|
--
|
|
END IF;
|
|
--
|
|
IF nvl(v_report_type
|
|
,'HTML') = 'HTML' THEN
|
|
--
|
|
-- Close the HTML page
|
|
--
|
|
store_line(htf.bodyclose);
|
|
store_line(htf.htmlclose);
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN v_return;
|
|
--
|
|
END return_results;
|
|
/**
|
|
-- Procedure to return the results of the selected report
|
|
-- @param x
|
|
*/
|
|
PROCEDURE return_results(p_item_name_array IN vc_arr
|
|
,p_item_value_array IN vc_arr) IS
|
|
--
|
|
v_dummy VARCHAR2(1);
|
|
--
|
|
BEGIN
|
|
--
|
|
v_dummy := return_results(p_item_name_array => p_item_name_array
|
|
,p_item_value_array => p_item_value_array);
|
|
--
|
|
FOR i IN (SELECT html_row
|
|
FROM report_html_elements
|
|
ORDER BY line) LOOP
|
|
--
|
|
htp.p(i.html_row);
|
|
--
|
|
END LOOP;
|
|
--
|
|
-- report_html_elements is persistant with connection pooling, therefore delete it.
|
|
--
|
|
DELETE report_html_elements;
|
|
--
|
|
END return_results;
|
|
--
|
|
PROCEDURE return_results_ref(p_item_name_array IN vc_arr
|
|
,p_item_value_array IN vc_arr
|
|
,html_cursor IN OUT t_ref_cursor) IS
|
|
--
|
|
v_dummy VARCHAR2(1);
|
|
--
|
|
BEGIN
|
|
--
|
|
v_dummy := return_results(p_item_name_array => p_item_name_array
|
|
,p_item_value_array => p_item_value_array);
|
|
--
|
|
OPEN html_cursor FOR
|
|
SELECT html_row
|
|
FROM report_html_elements;
|
|
--
|
|
END return_results_ref;
|
|
--
|
|
BEGIN
|
|
--
|
|
-- Package Initialization
|
|
-- Load the configuration record
|
|
--
|
|
get_report_configuration;
|
|
--
|
|
END geco_reporting;
|
|
/
|
|
|