Files
mip/Modules/MIP_FILES.pck
2008-03-11 12:10:01 +00:00

436 lines
15 KiB
Plaintext

CREATE OR REPLACE PACKAGE mip_files IS
-- Author : PRIESTJ
-- Created : 02/11/2007 10:59:52
-- Purpose : Handle files for the webMIP system
-- Public function and procedure declarations
FUNCTION quote_file_exists(p_qute_id NUMBER) RETURN BOOLEAN;
FUNCTION delete_file(p_id NUMBER
,p_doc_status VARCHAR2
,p_reason VARCHAR2) RETURN BOOLEAN;
FUNCTION drawing_file_exists(p_drwg_code VARCHAR2) RETURN BOOLEAN;
FUNCTION update_file_association(p_uri IN VARCHAR2
,p_description IN VARCHAR2
,p_docu_type IN VARCHAR2
,p_qute_id IN NUMBER
,p_enqu_id IN NUMBER
,p_drwg_code IN VARCHAR2) RETURN BOOLEAN;
FUNCTION set_file_association(p_uri IN VARCHAR2
,p_description IN VARCHAR2
,p_docu_type IN VARCHAR2
,p_rt_code IN VARCHAR2
,p_qute_id IN NUMBER
,p_enqu_id IN NUMBER
,p_drwg_code IN VARCHAR2
,p_doro_type IN VARCHAR2) RETURN BOOLEAN;
PROCEDURE export_table_to_csv(p_table IN VARCHAR2
,p_column_headers IN VARCHAR2
,p_delimiter IN VARCHAR2 DEFAULT ',');
END mip_files;
/
CREATE OR REPLACE PACKAGE BODY mip_files AS
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
END pl;
/*
FUNCTION is_file_over_size_limit
- takes the uri of the file to test for size and returns true if the file
- is over 3 meg (3145728 bytes) in size
%param p_uri - the uri of the file
*/
FUNCTION is_file_over_size_limit(p_uri VARCHAR2) RETURN BOOLEAN IS
l_file_size wwv_flow_files.doc_size%TYPE;
BEGIN
pl('is_file_over_size_limit:entry:' || p_uri);
SELECT doc_size
INTO l_file_size
FROM wwv_flow_files
WHERE NAME = p_uri;
pl('is_file_over_size_limit:exit:' || l_file_size);
RETURN(l_file_size > 3 * 1024 * 1024);
END is_file_over_size_limit;
/*
FUNCTION are_files_over_size_limit
- takes the enquiry id and an additional uri of the file to test for size
- and returns true if all the current files and plus additional file pointed
- by the uri are over 10 meg (10485760 bytes) in size
%param p_enqu_id - id of the enquiry to check the files for
*/
FUNCTION are_files_over_size_limit(p_enqu_id NUMBER) RETURN BOOLEAN IS
l_total_size NUMBER;
BEGIN
pl('are_files_over_size_limit:' || p_enqu_id);
SELECT SUM(doc_size)
INTO l_total_size
FROM documents d
,document_roles dr
,wwv_flow_files f
WHERE dr.enqu_id = p_enqu_id
AND d.id = dr.docu_id
AND d.uri = f.NAME;
pl('l_total_size:' || l_total_size);
RETURN(nvl(l_total_size
,0) > 10 * 1024 * 1024);
END are_files_over_size_limit;
/*
FUNCTION delete_file
- takes the id of a file held in the documents table and deletes the associated document
- in the documents, document_roles and wwv_flow_files tables and view
%param p_id - the id of the file
%param p_doc_status - the new status of the document one of "REMOVED USER", "REMOVED MALICIOUS", "REMOVED SIZE"
%param p_reason - a description of what the reason for deleting the file is
*/
FUNCTION delete_file(p_id NUMBER
,p_doc_status VARCHAR2
,p_reason VARCHAR2) RETURN BOOLEAN IS
l_uri documents.uri%TYPE;
CURSOR c_get_uri(cp_id NUMBER) IS
SELECT uri
FROM documents
WHERE id = cp_id;
BEGIN
IF NOT c_get_uri%ISOPEN THEN
OPEN c_get_uri(p_id);
END IF;
FETCH c_get_uri
INTO l_uri;
CLOSE c_get_uri;
--set up a deletion event for the document
INSERT INTO document_events
(docu_id
,dost_code
,event_date
,description
,id)
VALUES
(p_id
,p_doc_status
,SYSDATE
,p_reason
,doev_seq.NEXTVAL);
--delete the actual file from the database
DELETE wwv_flow_files
WHERE wwv_flow_files.NAME = l_uri;
RETURN TRUE;
END delete_file;
/*
FUNCTION quote_file_exists
- takes the quote id and searches for associated file in APEX Application
- Files, returns true if the file exists or false if it does not exist
%param p_qute_id - the quote id
*/
FUNCTION quote_file_exists(p_qute_id NUMBER) RETURN BOOLEAN IS
l_file_exists NUMBER;
CURSOR c_file_exists(cp_qute_id NUMBER) IS
SELECT 1
FROM wwv_flow_files
WHERE NAME = (SELECT d.uri
FROM documents d
,document_roles dr
WHERE dr.qute_id = cp_qute_id
AND d.id = dr.docu_id);
BEGIN
IF NOT c_file_exists%ISOPEN THEN
OPEN c_file_exists(p_qute_id);
END IF;
FETCH c_file_exists
INTO l_file_exists;
CLOSE c_file_exists;
IF l_file_exists IS NOT NULL
AND l_file_exists > 0 THEN
RETURN TRUE;
ELSE
RETURN FALSE;
END IF;
END quote_file_exists;
/*
FUNCTION drawing_file_exists
- takes the drawing code and searches for associated file in APEX Application
- Files, returns true if the file exists or false if it does not exist
%param p_drwg_code - the drawing code
*/
FUNCTION drawing_file_exists(p_drwg_code VARCHAR2) RETURN BOOLEAN IS
l_file_exists NUMBER;
CURSOR c_file_exists(cp_drwg_code VARCHAR2) IS
SELECT 1
FROM wwv_flow_files
WHERE NAME = (SELECT d.uri
FROM documents d
,document_roles dr
WHERE dr.drwg_code = cp_drwg_code
AND d.id = dr.docu_id);
BEGIN
IF NOT c_file_exists%ISOPEN THEN
OPEN c_file_exists(p_drwg_code);
END IF;
FETCH c_file_exists
INTO l_file_exists;
CLOSE c_file_exists;
IF l_file_exists IS NOT NULL
AND l_file_exists > 0 THEN
RETURN TRUE;
ELSE
RETURN FALSE;
END IF;
END drawing_file_exists;
/*
FUNCTION update_file_association
- updates the association between a object within webmip to a file held in the
- APEX application files view and ophans any existing files.
%param p_uri - the uri of the file (the contents of the name column in APEX application files)
%param p_description - description of the file, will be set in documents and document_roles table
%param p_docu_type - INDO (held within webmip db), EXDO (held outside webmip), FIDO (on file system)
%param p_rt_code - type of role for docment eg 'ENQUIRY SUPPORTING DOC' see role types table
%param p_qute_id - the quote id if applicable otherwise supply null
%param p_enqu_id - the enquiry id if applicable otherwise supply null
%param p_drwg_code - the drawing code if applicable otherwise supply null
*/
FUNCTION update_file_association(p_uri IN VARCHAR2
,p_description IN VARCHAR2
,p_docu_type IN VARCHAR2
,p_qute_id IN NUMBER
,p_enqu_id IN NUMBER
,p_drwg_code IN VARCHAR2) RETURN BOOLEAN IS
l_doc_id NUMBER;
BEGIN
--reference it in the documents table
INSERT INTO documents
(uri
,description
,id
,docu_type)
VALUES
(p_uri
,p_description
,docu_seq.NEXTVAL
,p_docu_type)
RETURNING id INTO l_doc_id;
--set up a role for the document
UPDATE document_roles
SET docu_id = l_doc_id
WHERE drwg_code = nvl(p_drwg_code
,'')
OR qute_id = nvl(p_qute_id
,0)
OR enqu_id = nvl(p_enqu_id
,0);
--set up an event for the document
INSERT INTO document_events
(docu_id
,dost_code
,event_date
,description
,id)
VALUES
(l_doc_id
,'AWAIT SCAN'
,SYSDATE
,p_description
,doev_seq.NEXTVAL);
--if it works then return true
RETURN TRUE;
END update_file_association;
/*
FUNCTION set_file_association
- sets the association between a object within webmip to a file held in the
- APEX application files view.
%param p_uri - the uri of the file (the contents of the name column in APEX application files)
%param p_description - description of the file, will be set in documents and document_roles table
%param p_docu_type - INDO (held within webmip db), EXDO (held outside webmip), FIDO (on file system)
%param p_rt_code - type of role for docment eg 'ENQUIRY SUPPORTING DOC' see role types table
%param p_qute_id - the quote id if applicable otherwise supply null
%param p_enqu_id - the enquiry id if applicable otherwise supply null
%param p_drwg_code - the drawing code if applicable otherwise supply null
%param p_doro_type - DRRO (for a drawing), ENDO (for an enquiry), QUDO (for a quote)
*/
FUNCTION set_file_association(p_uri IN VARCHAR2
,p_description IN VARCHAR2
,p_docu_type IN VARCHAR2
,p_rt_code IN VARCHAR2
,p_qute_id IN NUMBER
,p_enqu_id IN NUMBER
,p_drwg_code IN VARCHAR2
,p_doro_type IN VARCHAR2) RETURN BOOLEAN IS
l_doc_id NUMBER;
l_success BOOLEAN;
BEGIN
pl('set_file_association:entry:'|| p_uri || ':'||p_docu_type||':'||p_doro_type);
--reference it in the documents table
INSERT INTO documents
(uri
,description
,id
,docu_type)
VALUES
(p_uri
,p_description
,docu_seq.NEXTVAL
,p_docu_type)
RETURNING id INTO l_doc_id;
--set up a role for the document
INSERT INTO document_roles
(rt_code
,start_date
,description
,qute_id
,enqu_id
,drwg_code
,id
,doro_type
,docu_id)
VALUES
(p_rt_code
,SYSDATE
,p_description
,p_qute_id
,p_enqu_id
,p_drwg_code
,doro_seq.NEXTVAL
,p_doro_type
,l_doc_id);
--set up an event for the document
INSERT INTO document_events
(docu_id
,dost_code
,event_date
,description
,id)
VALUES
(l_doc_id
,'AWAIT SCAN'
,SYSDATE
,p_description
,doev_seq.NEXTVAL);
IF p_rt_code = 'ENQUIRY SUPPORTING DOC'
AND NOT p_enqu_id IS NULL THEN
IF (are_files_over_size_limit(p_enqu_id) OR
is_file_over_size_limit(p_uri)) THEN
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');
RETURN FALSE;
END IF;
END IF;
--if it works then return true
pl('set_file_association:exit:true');
RETURN TRUE;
END set_file_association;
/*
PROCEDURE export_data_to_csv
- allows an admin user to create a CSV export of a table in webMIP.
- This function will be used to extract data from the online webMIP system
- and pull the data into Metering I&C's backend systems.
%param p_table - the name of the table we're to export
%param p_column_headers - tables column names be exported as a header
%param p_delimiter - what is the delimiter value is for each field (default ',')
*/
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
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);
dbms_sql.parse(l_cursor
,l_select
,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
--
-- Set the header MIME type
owa_util.mime_header('application/octet'
,FALSE);
-- Set the name of the file
htp.p('Content-Disposition: attachment; filename="' ||
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);
END IF;
--
END IF;
--
-- Main CSV output
dbms_sql.column_value(l_cursor
,1
,l_return);
--
htp.p(l_return);
--
END LOOP;
--
END export_table_to_csv;
END mip_files;
/