Addresses #444. The select/header lists exceeded the maximum length of the varchar2 allocated to hold them. Rewrote without the need for the varchar2s.

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@4196 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-04-01 17:13:26 +00:00
parent 7db9f2148e
commit d81fe866b1

View File

@@ -33,13 +33,16 @@ END mip_files;
/
CREATE OR REPLACE PACKAGE BODY mip_files AS
PROCEDURE pl(p_in VARCHAR2, p_line NUMBER DEFAULT NULL) IS
PROCEDURE pl(p_in VARCHAR2
,p_line NUMBER DEFAULT NULL) IS
BEGIN
NULL;
-- $IF $$DEBUGGING OR mip_debug_constants.debugging OR mip_debug_constants.files
-- $THEN
mip_debug.pl(p_unit => $$PLSQL_UNIT,p_in => p_in, p_line => p_line);
-- $END
NULL;
-- $IF $$DEBUGGING OR mip_debug_constants.debugging OR mip_debug_constants.files
-- $THEN
mip_debug.pl(p_unit => $$PLSQL_UNIT
,p_in => p_in
,p_line => p_line);
-- $END
END pl;
/*
@@ -270,7 +273,8 @@ CREATE OR REPLACE PACKAGE BODY mip_files AS
l_doc_id NUMBER;
l_success BOOLEAN;
BEGIN
pl('set_file_association:entry:'|| p_uri || ':'||p_docu_type||':'||p_doro_type);
pl('set_file_association:entry:' || p_uri || ':' || p_docu_type || ':' ||
p_doro_type);
--reference it in the documents table
INSERT INTO documents
(uri
@@ -325,7 +329,7 @@ CREATE OR REPLACE PACKAGE BODY mip_files AS
l_success := delete_file(l_doc_id
,'REMOVED SIZE'
,'webMIP determined the file or files to be too big');
pl('set_file_association:exit:false');
pl('set_file_association:exit:false');
RETURN FALSE;
END IF;
END IF;
@@ -346,60 +350,48 @@ CREATE OR REPLACE PACKAGE BODY mip_files AS
PROCEDURE export_table_to_csv(p_table IN VARCHAR2
,p_column_headers IN VARCHAR2
,p_delimiter IN VARCHAR2 DEFAULT ',') IS
l_select VARCHAR2(2000); --will hold our dynamically created sql query
l_cursor INTEGER DEFAULT dbms_sql.open_cursor; --a handle for the recordset we can then loop through
l_status INTEGER;
l_return VARCHAR2(4000);
l_found BOOLEAN := TRUE;
l_headers VARCHAR(2000); --used to collect the column headers
l_cursor INTEGER DEFAULT dbms_sql.open_cursor; --a handle for the recordset we can then loop through
l_status INTEGER;
l_column_value VARCHAR2(2000);
l_first_row BOOLEAN := TRUE;
l_column_count NUMBER;
l_separator VARCHAR2(10);
l_headers BOOLEAN := upper(p_column_headers) = 'YES';
l_tab_column_descriptions dbms_sql.desc_tab;
BEGIN
dbms_output.put_line('me is here');
-- Build the dynamic SQL statement to get the tables column names
FOR f IN (SELECT column_name
FROM user_tab_columns
WHERE table_name = upper(p_table)
ORDER BY column_id) LOOP
--
-- AG's clever delimiting ensures that the rows from the table are output
-- in a nice CSV format
l_select := l_select || '''"''||' || f.column_name || '||''"' ||
p_delimiter || '''||';
--
-- Get the header row, slightly inefficient in that we may not need to
-- do it every time
l_headers := l_headers || f.column_name || p_delimiter;
--
END LOOP;
--
-- Trim the unnecessary additional delimiting chars on the headers and
-- add a carriage return
l_headers := rtrim(l_headers
,p_delimiter) || chr(13);
--
-- build the dynamic SQL that will return all the table rows
l_select := 'SELECT ' || rtrim(l_select
,'||') || chr(13) || chr(10) || ' FROM ' ||
p_table;
--
-- Now we have the select, let's execute it
--
dbms_output.put_line(l_select);
pl('export_table_to_csv:entry:' || p_table
,$$PLSQL_LINE);
dbms_sql.parse(l_cursor
,l_select
,'select id from ' || p_table
,dbms_sql.native);
--
dbms_sql.define_column(l_cursor
,1
,l_return
,4000);
--
l_status := dbms_sql.EXECUTE(l_cursor); --could be used for further manipulation
--
WHILE (dbms_sql.fetch_rows(l_cursor) > 0) LOOP
--
IF l_found THEN
--
dbms_sql.describe_columns(l_cursor
,l_column_count
,l_tab_column_descriptions);
FOR l_idx IN 1 .. l_column_count LOOP
BEGIN
dbms_sql.define_column(l_cursor
,l_idx
,l_column_value
,2000);
EXCEPTION
WHEN OTHERS THEN
IF (SQLCODE = -1007) THEN
EXIT;
ELSE
RAISE;
END IF;
END;
END LOOP;
l_status := dbms_sql.EXECUTE(l_cursor);
LOOP
EXIT WHEN(dbms_sql.fetch_rows(l_cursor) <= 0);
IF l_first_row THEN
-- Set the header MIME type
owa_util.mime_header('application/octet'
,FALSE);
@@ -408,27 +400,45 @@ CREATE OR REPLACE PACKAGE BODY mip_files AS
lower(p_table) || '.csv"');
-- Close the HTTP Header
owa_util.http_header_close;
--
l_found := FALSE;
--
-- If the user has requested that the tables column names be exported
-- then display them
IF upper(p_column_headers) = 'YES' THEN
--print column headers
htp.p(l_headers);
IF l_headers THEN
l_separator := '';
FOR l_idx IN 1 .. l_column_count LOOP
IF l_idx <> l_column_count THEN
htp.prn(l_separator || '"'||l_tab_column_descriptions(l_idx).col_name||'"');
ELSE
htp.p(l_separator || '"'||l_tab_column_descriptions(l_idx).col_name||'"');
END IF;
l_separator := p_delimiter;
END LOOP;
END IF;
--
l_first_row := FALSE;
END IF;
--
-- Main CSV output
dbms_sql.column_value(l_cursor
,1
,l_return);
--
htp.p(l_return);
--
l_separator := '';
FOR l_idx IN 1 .. l_column_count LOOP
dbms_sql.column_value(l_cursor
,l_idx
,l_column_value);
IF l_idx <> l_column_count THEN
htp.prn(l_separator || '"'||l_column_value||'"');
ELSE
htp.p(l_separator || '"'||l_column_value||'"');
END IF;
l_separator := p_delimiter;
END LOOP;
END LOOP;
--
dbms_sql.close_cursor(l_cursor);
pl('export_table_to_csv:exit'
,$$PLSQL_LINE);
EXCEPTION
WHEN OTHERS THEN
pl('export_table_to_csv:EXCEPTION:' || SQLERRM
,$$PLSQL_LINE);
RAISE;
END export_table_to_csv;
END mip_files;