CREATE OR REPLACE PACKAGE BODY amfr_excel IS -- -- Private -- c_excel_mime CONSTANT VARCHAR2(100) := 'application/vnd.ms-excel'; c_xml_mime CONSTANT VARCHAR2(100) := 'application/vnd.ms-excel'; --'application/xml'; -- FUNCTION j_readworkbook(p_docu_id IN VARCHAR2) RETURN VARCHAR2 AS LANGUAGE JAVA NAME 'advantica.oracle.accessmanager.amfr_excel_j.amfr_excel_j.readWorkBook(java.lang.String) return java.lang.String'; -- -- Write spreadsheet - returns document identifier -- FUNCTION j_writeworkbook(p_spreadsheet_id IN VARCHAR2 ,p_sheet_name IN VARCHAR2) RETURN NUMBER AS LANGUAGE JAVA NAME 'advantica.oracle.accessmanager.amfr_excel_j.amfr_excel_j.writeWorkBook(java.lang.String, java.lang.String) return long'; -- -- Routine to write XML style spreadsheet from PL/SQL -- FUNCTION p_writeworkbook ( p_spreadsheet_id IN VARCHAR2 , p_worksheet_name IN VARCHAR2 ) RETURN documents.docu_id%TYPE IS -- -- Global Private Declaration -- c_cr CONSTANT VARCHAR2(2) := CHR(10); l_style VARCHAR2(100) := NULL; l_last_row NUMBER; -- l_document BLOB; l_docu_id DOCUMENTS.docu_Id%TYPE; -- -- Global Private Procedures -- PROCEDURE store (p_text IN VARCHAR2) IS BEGIN -- dbms_lob.writeappend(lob_loc => l_document ,amount => LENGTH(p_text) ,buffer => utl_raw.cast_to_raw(p_text) ); -- END; -- PROCEDURE openworkbook IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := '' || c_cr; l_return := l_return || ''||c_cr; l_return := l_return || ''; -- store(l_return); -- END openworkbook; -- PROCEDURE closeworkbook IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''; -- store(l_return); -- END closeworkbook; -- PROCEDURE openworksheet (p_name IN VARCHAR2 DEFAULT 'Sheet1') IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := '' || c_cr; l_return := l_return || ''; -- store(l_return); -- END openworksheet; -- PROCEDURE closeworksheet IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := '' || c_cr; l_return := l_return || ''; -- store(l_return); -- END closeworksheet; -- PROCEDURE openrow ( p_index IN VARCHAR , p_height IN VARCHAR2 , p_style IN VARCHAR2 DEFAULT NULL ) IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ' '; -- store(l_return); -- END openrow; -- PROCEDURE closerow IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''; -- store(l_return); -- END closerow; -- PROCEDURE printcolumn ( p_index IN VARCHAR2 , p_width IN VARCHAR2 DEFAULT '80' ) IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''; -- store(l_return); -- END printcolumn; -- PROCEDURE openstyles IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''; -- store(l_return); -- END openstyles; -- PROCEDURE closestyles IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''; -- store(l_return); -- END closestyles; -- PROCEDURE printstyle ( p_styleid IN VARCHAR2 , p_formatmask IN VARCHAR2 , p_border IN VARCHAR2 , p_background IN VARCHAR2 , p_font IN VARCHAR2 , p_fontsize IN VARCHAR2 , p_align IN VARCHAR2 , p_wrap IN VARCHAR2 ) IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''||c_cr; -- -- IF p_formatmask IS NOT NULL THEN -- NULL; -- END IF; -- IF p_border IS NOT NULL THEN -- NULL; -- not used at the moment? -- END IF; -- IF p_background IS NOT NULL THEN -- l_return := l_return ||' '; -- END IF; -- IF p_font IS NOT NULL OR p_fontsize IS NOT NULL THEN -- l_return := l_return ||''; -- END IF; -- IF p_align IS NOT NULL THEN -- l_return := l_return || ' '; -- END IF; -- IF p_wrap IS NOT NULL THEN -- NULL; -- END IF; -- l_return := l_return || ''; -- store(l_return); -- END printstyle; -- PROCEDURE printcell ( p_index IN VARCHAR DEFAULT '1' , p_value IN VARCHAR DEFAULT NULL , p_type IN VARCHAR DEFAULT 'String' , p_style IN VARCHAR DEFAULT NULL , p_merge IN VARCHAR DEFAULT '0' ) IS -- l_return VARCHAR2(1000); -- BEGIN -- l_return := ''||c_cr; -- l_return := l_return || ''||p_value||''||c_cr; -- l_return := l_return || ''; -- store((l_return)); -- END printcell; -- BEGIN -- -- Init blob -- dbms_lob.createtemporary(l_document,true); -- -- Open the workbook -- openworkbook; -- -- Produce a list of styles in use -- openstyles; -- FOR style IN ( SELECT ROWNUM AS styleid, z.* FROM ( SELECT DISTINCT cell_format_mask ,cell_border ,cell_background ,cell_font ,cell_fontsize ,cell_align ,cell_wrap FROM gtt_spreadsheet gtsp WHERE gtsp.spreadsheet_id = p_spreadsheet_id ORDER BY cell_format_mask ,cell_border ,cell_background ,cell_font ,cell_fontsize ,cell_align ,cell_wrap ) z ) LOOP -- printstyle( p_styleid => style.styleid , p_formatmask => style.cell_format_mask , p_border => style.cell_border , p_background => style.cell_background , p_font => style.cell_font , p_fontsize => style.cell_fontsize , p_align => style.cell_align , p_wrap => style.cell_wrap ); -- END LOOP; -- closestyles; -- openworksheet(p_name => p_worksheet_name); -- -- -- FOR colwid IN ( SELECT amfr_excel.convert_x(x_axis) + 1 AS col_index , MAX(LEAST(100,gtsp.col_width)) AS width FROM gtt_spreadsheet gtsp WHERE gtsp.spreadsheet_id = p_spreadsheet_id GROUP BY amfr_excel.convert_x(x_axis) + 1 ORDER BY amfr_excel.convert_x(x_axis) + 1 ) LOOP -- printcolumn( p_index => colwid.col_index , p_width => colwid.width ); -- END LOOP; -- -- Now loop around the detail -- FOR ss IN ( SELECT amfr_excel.convert_x(x_axis) + 1 AS x_axis ,amfr_excel.convert_y(y_axis) + 1 AS y_axis ,cell_value ,DECODE(cell_datatype, 'D', 'DateTime' , 'N', 'Number' , 'String' ) AS cell_datatype ,NVL(cell_merge,0) AS cell_merge ,col_width ,row_height ,cell_format_mask ,cell_border ,cell_background ,cell_font ,cell_fontsize ,cell_align ,cell_wrap FROM gtt_spreadsheet gtsp WHERE gtsp.spreadsheet_id = p_spreadsheet_id ORDER BY y_axis, x_axis ) LOOP -- IF ss.y_axis <> l_last_row OR l_last_row IS NULL THEN -- IF l_last_row IS NOT NULL THEN -- -- Close the previous row -- closerow; -- END IF; -- -- Open the new row -- openrow(p_index => ss.y_axis ,p_height => ss.row_height ,p_style => NULL ); -- -- Save the row number -- l_last_row := ss.y_axis; -- END IF; -- l_style := NULL; -- FOR style IN (SELECT ROWNUM AS styleid, z.* FROM ( SELECT DISTINCT cell_format_mask ,cell_border ,cell_background ,cell_font ,cell_fontsize ,cell_align ,cell_wrap FROM gtt_spreadsheet gtsp WHERE gtsp.spreadsheet_id = p_spreadsheet_id ORDER BY cell_format_mask ,cell_border ,cell_background ,cell_font ,cell_fontsize ,cell_align ,cell_wrap ) z ) LOOP -- IF NVL(style.cell_format_mask,'xyz') = NVL(ss.cell_format_mask,'xyz') AND NVL(style.cell_border,'xyz') = NVL(ss.cell_border,'xyz') AND NVL(style.cell_background,'xyz') = NVL(ss.cell_background,'xyz') AND NVL(style.cell_font,'xyz') = NVL(ss.cell_font,'xyz') AND NVL(style.cell_fontsize,'xyz') = NVL(ss.cell_fontsize,'xyz') AND NVL(style.cell_align,'xyz') = NVL(ss.cell_align,'xyz') AND NVL(style.cell_wrap,'xyz') = NVL(ss.cell_wrap,'xyz') THEN -- l_style := style.styleid; -- END IF; -- END LOOP; -- printcell ( p_value => ss.cell_value , p_index => ss.x_axis , p_merge => ss.cell_merge , p_type => ss.cell_datatype , p_style => l_style ); -- END LOOP; -- IF l_last_row IS NOT NULL THEN -- -- We have a last row specified therefore we have had at least one row. Close the last row -- closerow; -- END IF; -- closeworksheet; -- closeworkbook; -- INSERT INTO documents (NAME ,blob_content ,content_type ,mime_type) VALUES (p_worksheet_name ,l_document ,'BLOB' ,c_xml_mime) RETURNING docu_id INTO l_docu_id; -- RETURN l_docu_id; -- END p_writeworkbook; -- -- -- FUNCTION get_cont_conf_format ( p_cont_id IN contracts.cont_id%TYPE ) RETURN VARCHAR2 IS -- l_return VARCHAR2(10); -- BEGIN -- SELECT coop.conf_type INTO l_return FROM contract_options coop WHERE coop.cont_id = p_cont_id; -- RETURN l_return; -- END get_cont_conf_format; -- -- Public -- FUNCTION convert_x ( p_x_axis IN VARCHAR2 ) RETURN NUMBER IS -- l_x_axis VARCHAR2(20); -- l_return NUMBER := 0; -- BEGIN -- l_x_axis := UPPER(p_x_axis); -- -- Check validity of input string, Excel doesn't handle 3 chr columns so neither should we -- IF LENGTH(l_x_axis) BETWEEN 1 AND 2 AND NVL(LENGTH(REPLACE(TRANSLATE(l_x_axis,'ABCDEFGHIJKLMNOPQRSTUVWXYZ',' '),' ','')),0) = 0 THEN -- FOR i IN 1..LENGTH(l_x_axis) LOOP -- l_return := l_return + (ASCII(SUBSTR(l_x_axis,i,1))-64)*GREATEST(((LENGTH(l_x_axis)-i)*26),1); -- END LOOP; -- -- Excel starts at 1 arrays start at 0 so minus 1 -- l_return := l_return -1; -- END IF; -- RETURN l_return; -- END convert_x; -- FUNCTION convert_y ( p_y_axis IN NUMBER ) RETURN NUMBER IS BEGIN -- -- Excel starts at 1 array starts at 0 so minus 1 -- RETURN p_y_axis - 1; -- END convert_y; -- PROCEDURE download ( p_docu_id IN documents.docu_id%TYPE ) IS -- l_document_contents documents.blob_content%TYPE; l_mime_type documents.mime_type%TYPE; l_document_name documents.name%TYPE; -- BEGIN -- -- Get the document out of the table ready for direct transmission -- BEGIN -- SELECT doc.blob_content ,doc.mime_type ,doc.name INTO l_document_contents ,l_mime_type ,l_document_name FROM documents doc WHERE doc.docu_id = p_docu_id; -- EXCEPTION WHEN OTHERS THEN -- NULL; -- END; -- owa_util.mime_header(l_mime_type, FALSE); htp.p('Content-Length: '||dbms_lob.getlength(l_document_contents)); htp.p('Content-Disposition: attachment; filename='||l_document_name); owa_util.http_header_close; -- IF l_document_contents IS NOT NULL THEN wpg_docload.download_file(l_document_contents); END IF; -- END download; -- PROCEDURE download ( p_conf_id IN confirmations.conf_id%TYPE ) IS -- l_document_contents documents.blob_content%TYPE; l_mime_type documents.mime_type%TYPE; -- l_document_name documents.name%TYPE; l_gas_day DATE; l_cust_code customers.code%TYPE; -- BEGIN -- -- Get the document out of the table ready for direct transmission -- BEGIN -- SELECT conf.confirmation ,conf.gas_day ,cust.code ,conf.conf_file_type INTO l_document_contents ,l_gas_day ,l_cust_code ,l_mime_type FROM confirmations conf ,contracts cont ,customers cust WHERE conf.conf_id = p_conf_id AND conf.cont_id = cont.cont_id AND cont.cust_id = cust.cust_id; -- EXCEPTION WHEN OTHERS THEN -- NULL; -- END; -- l_document_name := REPLACE(l_cust_code,' ','_')||'_'||TO_CHAR(l_gas_day, 'YYYYMMDD')||'_'||TO_CHAR(p_conf_id); -- IF l_mime_type = 'E' THEN -- l_mime_type := c_excel_mime; l_document_name := l_document_name||'.xls'; -- ELSIF l_mime_type = 'X' THEN -- l_mime_type := c_xml_mime; l_document_name := l_document_name||'.xml'; -- ELSE -- l_mime_type := NULL; -- END IF; -- owa_util.mime_header(l_mime_type, FALSE); htp.p('Content-Length: '||dbms_lob.getlength(l_document_contents)); htp.p('Content-Disposition: attachment; filename='||l_document_name); owa_util.http_header_close; -- IF l_document_contents IS NOT NULL THEN wpg_docload.download_file(l_document_contents); END IF; -- END download; -- PROCEDURE download ( p_nomi_id IN nominations.nomi_id%TYPE ) IS -- l_document_contents documents.blob_content%TYPE; l_mime_type documents.mime_type%TYPE; l_document_name documents.name%TYPE := 'nomination_'||TO_CHAR(p_nomi_id); -- BEGIN -- -- Check security, code for view nominations -- IF NOT caco_security.security_check(p_package_name => 'efnow101$') THEN -- RETURN; -- END IF; -- -- Get the document out of the table ready for direct transmission -- BEGIN -- SELECT conf.confirmation ,conf.conf_file_type INTO l_document_contents ,l_mime_type FROM confirmations conf ,contracts cont ,nominations nomi WHERE conf.nomi_id = p_nomi_id AND conf.confirmation_type = 'NO' AND nomi.nomi_id = conf.nomi_id AND nomi.cont_id = cont.cont_id AND cont.cust_id = caco_utilities.get_cust_id; -- EXCEPTION WHEN OTHERS THEN -- NULL; -- END; -- IF l_mime_type = 'E' THEN -- l_mime_type := c_excel_mime; l_document_name := l_document_name||'.xls'; -- ELSIF l_mime_type = 'X' THEN -- l_mime_type := c_xml_mime; l_document_name := l_document_name||'.xml'; -- ELSE -- l_mime_type := NULL; -- END IF; -- owa_util.mime_header(l_mime_type, FALSE); htp.p('Content-Length: '||dbms_lob.getlength(l_document_contents)); htp.p('Content-Disposition: attachment; filename='||l_document_name); owa_util.http_header_close; -- IF l_document_contents IS NOT NULL THEN wpg_docload.download_file(l_document_contents); END IF; -- END download; -- FUNCTION get_spte_name ( p_cont_id IN contracts.cont_id%TYPE ) RETURN VARCHAR2 IS -- l_return VARCHAR(100); -- BEGIN -- IF p_cont_id IS NOT NULL THEN -- SELECT UPPER(spte.name) INTO l_return FROM contracts cont ,spreadsheet_templates spte WHERE spte.spte_id = cont.spte_id AND spte.spte_type = 'NOST' AND cont.cont_id = p_cont_id; -- END IF; -- RETURN l_return; -- END get_spte_name; -- PROCEDURE get_template ( p_id IN NUMBER , p_type IN VARCHAR2 , p_nomi_conf_id IN NUMBER DEFAULT NULL , p_mode IN VARCHAR2 DEFAULT 'DOWNLOAD' ) IS -- l_spreadsheet_id gtt_spreadsheet.spreadsheet_id%TYPE; l_docu_id documents.docu_id%TYPE; l_spte_id spreadsheet_templates.spte_id%TYPE; l_cust_id customers.cust_id%TYPE; -- l_conf_type confirmations.conf_file_type%TYPE; -- -- Generic value for tag replacement -- l_value VARCHAR2(1000); l_start_date DATE; l_end_date DATE; l_num_days NUMBER; l_offset_reduction NUMBER := 0; l_cont_long_day BOOLEAN; l_only_short_day BOOLEAN; l_loop_counter NUMBER := 1; -- l_first_row BOOLEAN := TRUE; l_last_name categories.name%TYPE; l_col_span NUMBER := 0; -- -- Known tags -- c_cont_placeholder CONSTANT VARCHAR2(100) := '{CONTRACT_ID}'; c_gday_placeholder CONSTANT VARCHAR2(100) := '{GAS_DAY}'; c_gday2_placeholder CONSTANT VARCHAR2(100) := '{GAS_DAY_TO}'; c_nnpcv_placeholder CONSTANT VARCHAR2(100) := '{NOM_NET_POINT_CAT_VALS}'; c_nepo_code CONSTANT VARCHAR2(100) := '{NETWORK_POINT_CODE}'; c_nepo_name CONSTANT VARCHAR2(100) := '{NETWORK_POINT_NAME}'; c_cate_name CONSTANT VARCHAR2(100) := '{CAT_NAME}'; c_cate_units CONSTANT VARCHAR2(100) := '{CAT_UNITS}'; c_cust_name CONSTANT VARCHAR2(100) := '{CUSTOMER_NAME}'; -- CURSOR cur_spte ( p_spte_id IN spreadsheet_templates.spte_id%TYPE ) IS SELECT l_spreadsheet_id ,sptv.x_axis ,sptv.y_axis ,sptv.cell_value ,sptv.cell_datatype ,sptv.cell_format_mask ,sptv.cell_border ,sptv.cell_background ,sptv.cell_merge ,sptv.cell_font ,sptv.cell_fontsize ,sptv.cell_align ,sptv.col_width ,sptv.row_height ,sptv.cell_wrap ,spte.name FROM spreadsheet_templates spte ,spreadsheet_template_values sptv WHERE spte.spte_id = sptv.spte_id AND spte.spte_id = p_spte_id; -- l_r_spte cur_spte%ROWTYPE; -- PROCEDURE insert_cell ( p_r_spte IN cur_spte%ROWTYPE , p_value_overload IN VARCHAR2 DEFAULT NULL , p_x_increment IN NUMBER DEFAULT 0 , p_y_increment IN NUMBER DEFAULT 0 , p_span IN NUMBER DEFAULT NULL ) IS -- l_x_axis VARCHAR2(2) := NULL; -- BEGIN -- IF p_x_increment > 0 THEN -- l_x_axis := CHR(ASCII(p_r_spte.x_axis)+p_x_increment); -- END IF; -- INSERT INTO gtt_spreadsheet ( spreadsheet_id , x_axis , y_axis , cell_value , cell_datatype , cell_format_mask , cell_border , cell_background , cell_merge , cell_font , cell_fontsize , cell_align , col_width , row_height , cell_wrap ) VALUES ( p_r_spte.l_spreadsheet_id , NVL(l_x_axis, p_r_spte.x_axis) , p_r_spte.y_axis + p_y_increment , NVL(p_value_overload, p_r_spte.cell_value) , p_r_spte.cell_datatype , p_r_spte.cell_format_mask , p_r_spte.cell_border , p_r_spte.cell_background , NVL(p_span, p_r_spte.cell_merge) , p_r_spte.cell_font , p_r_spte.cell_fontsize , p_r_spte.cell_align , p_r_spte.col_width , p_r_spte.row_height , p_r_spte.cell_wrap ); -- END insert_cell; -- BEGIN -- IF p_type = gc_nomination THEN -- SELECT spte_id ,cust_id INTO l_spte_id ,l_cust_id FROM contracts cont WHERE cont.cont_id = p_id; -- SELECT spte_seq.NEXTVAL INTO l_spreadsheet_id FROM DUAL; -- -- Only get dates from a nomination if we are looking at a nomination -- IF p_nomi_conf_id IS NOT NULL THEN -- BEGIN SELECT MIN(nnpcv.gas_day) ,MAX(nnpcv.gas_day) INTO l_start_date ,l_end_date FROM nom_net_point_cat_vals nnpcv WHERE nnpcv.nomi_id = p_nomi_conf_id; EXCEPTION WHEN OTHERS THEN NULL; END; -- ELSE -- -- Think of something else! -- l_start_date := TRUNC(SYSDATE) + NVL(cout_system_configuration.get_configuration_item('G_NOM_DATE_OFFSET'),1); l_end_date := l_start_date + cout_system_configuration.get_configuration_item('G_MULTI_DAY_NOM_DAYS')-1; -- END IF; -- -- Work out if we need to worry about the long and short days -- l_loop_counter := (l_end_date - l_start_date) +1; l_only_short_day := FALSE; l_cont_long_day := FALSE; -- -- Check to see if the period we are looking at contains the long day, or only contains the short day -- FOR i IN 1..l_loop_counter LOOP -- IF cout_dates.hours_in_gas_day(l_start_date + (i-1)) = 25 THEN l_cont_long_day := TRUE; END IF; -- END LOOP; -- IF (get_spte_name(p_id) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) OR l_loop_counter = 1 ) AND cout_dates.hours_in_gas_day(l_start_date) = 23 THEN -- l_only_short_day := TRUE; -- END IF; -- -- Now loop around the template -- OPEN cur_spte ( l_spte_id ); -- LOOP -- FETCH cur_spte INTO l_r_spte; -- EXIT WHEN cur_spte%NOTFOUND; -- IF l_r_spte.cell_value LIKE '{%}' THEN -- -- Candidate for tag replacement, loop through our known tags -- -- {CAT_NAME} -- {CAT_UNITS} -- {CONTRACT_ID} -- {CUSTOMER_NAME} -- {GAS_DAY} -- {NETWORK_POINT_CODE} -- {NETWORK_POINT_NAME} -- {NOM_NET_POINT_CAT_VALS} -- l_value := NULL; -- IF l_r_spte.cell_value = c_cont_placeholder THEN -- -- Populate cell with Contract ID -- SELECT cont.contract_number INTO l_value FROM contracts cont WHERE cont.cont_id = p_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_gday_placeholder THEN -- -- Populate cell with Gas Day -- IF UPPER(l_r_spte.name) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) THEN -- l_value := TO_CHAR(l_start_date, g_date_format); -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- ELSE -- -- Need to consider multiple days and sites -- FOR site_incr IN ( SELECT rownum FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = p_id AND nepo.nepo_id = cnp.nepo_id AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(p_id) = 'Y') OR efno_contracts.emo_contract(p_id) = 'N')) LOOP -- -- Now loop around the multiple days -- FOR date_loop IN 1..((l_end_date - l_start_date)+1) LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => TO_CHAR(l_start_date + (date_loop -1), g_date_format) , p_y_increment => ((site_incr.rownum - 1) * ((l_end_date - l_start_date)+1) + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END IF; -- END IF; -- IF l_r_spte.cell_value = c_gday2_placeholder THEN -- -- Populate cell with Gas Day -- -- l_value := TO_CHAR(l_end_date, g_date_format); -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); END IF; -- IF l_r_spte.cell_value = c_cust_name THEN -- -- Populate cell with Customer Name -- SELECT cust.name INTO l_value FROM contracts cont ,customers cust WHERE cont.cont_id = p_id AND cont.cust_id = cust.cust_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_nepo_code THEN -- -- Populate cell with Network Point Code -- IF UPPER(l_r_spte.name) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) THEN -- l_num_days := 1; -- ELSE -- l_num_days := (l_end_date - l_start_date) +1; -- END IF; -- FOR site_rec IN ( SELECT site ,rownum FROM ( SELECT nepo.code AS site FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = p_id AND nepo.nepo_id = cnp.nepo_id AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(p_id) = 'Y') OR efno_contracts.emo_contract(p_id) = 'N') ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => site_rec.site , p_y_increment => ((site_rec.rownum - 1) * l_num_days + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_nepo_name THEN -- -- Populate cell with Network Point Name -- IF UPPER(l_r_spte.name) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) THEN -- l_num_days := 1; -- ELSE -- l_num_days := (l_end_date - l_start_date) + 1; -- END IF; -- FOR site_rec IN ( SELECT site ,rownum FROM ( SELECT nepo.name AS site FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = p_id AND nepo.nepo_id = cnp.nepo_id AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(p_id) = 'Y') OR efno_contracts.emo_contract(p_id) = 'N') ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => site_rec.site , p_y_increment => ((site_rec.rownum - 1) * l_num_days + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_cate_name THEN -- -- Populate cell with Category Name -- FOR cate IN (SELECT x.*, ROWNUM FROM ( SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,coca.display_sequence FROM contract_categories coca ,categories cate WHERE cate.cate_id = coca.cate_id AND coca.cont_id = p_id ORDER BY coca.display_sequence) x ) LOOP -- IF (cate.display_cond = 'LO' AND l_cont_long_day) OR (cate.display_cond = 'SH' AND NOT l_only_short_day) OR cate.display_cond = 'AL' THEN -- IF (l_last_name = cate.name OR l_first_row) THEN -- l_col_span := l_col_span + 1; l_last_name := cate.name; l_first_row := FALSE; -- ELSE -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_last_name , p_x_increment => l_offset_reduction , p_span => l_col_span -1 ); -- l_offset_reduction := l_offset_reduction + l_col_span; l_last_name := cate.name; l_col_span := 1; -- END IF; -- END IF; -- END LOOP; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_last_name , p_x_increment => l_offset_reduction , p_span => l_col_span -1 ); -- END IF; -- IF l_r_spte.cell_value = c_cate_units THEN -- -- Populate cell with Category Units -- l_offset_reduction := -1; -- FOR cat IN (SELECT rownum, units, display_cond FROM (SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,row_number() over (partition by cate.name order by coca.display_sequence) disp_head ,sq1.span ,coca.display_sequence FROM contract_categories coca ,categories cate , (SELECT cate2.name ,count(*) as span FROM contract_categories coca2 ,categories cate2 WHERE coca2.cont_id = p_id AND coca2.cate_id = cate2.cate_id GROUP BY cate2.name) sq1 WHERE cate.cate_id = coca.cate_id AND coca.cont_id = p_id AND sq1.name = cate.name ORDER BY coca.display_sequence ) ) LOOP -- IF (cat.display_cond = 'LO' AND l_cont_long_day) OR (cat.display_cond = 'SH' AND NOT l_only_short_day) OR cat.display_cond = 'AL' THEN -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => cat.units , p_x_increment => cat.rownum + l_offset_reduction ); -- ELSE l_offset_reduction := l_offset_reduction - 1; END IF; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_nnpcv_placeholder THEN -- -- Check for multi or single gas days -- IF UPPER(l_r_spte.name) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) THEN -- l_num_days := 1; -- ELSE -- l_num_days := l_end_date - l_start_date + 1; -- END IF; -- -- Populate cell with Network Point Values, if required -- IF p_nomi_conf_id IS NOT NULL THEN -- -- Populate cells with nomination -- FOR site_incr IN ( SELECT rownum - 1 AS y_incr ,conp_id FROM (SELECT cnp.conp_id FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = p_id AND cnp.nepo_id = nepo.nepo_id AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(p_id) = 'Y') OR efno_contracts.emo_contract(p_id) = 'N') ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- l_offset_reduction := 0; -- FOR cat_incr IN (SELECT x.*, ROWNUM - 1 AS x_incr FROM ( SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,coca.display_sequence FROM contract_categories coca ,categories cate WHERE cate.cate_id = coca.cate_id AND coca.cont_id = p_id ORDER BY coca.display_sequence) x ) LOOP -- IF (cat_incr.display_cond = 'LO' AND l_cont_long_day) OR (cat_incr.display_cond = 'SH' AND NOT l_only_short_day) OR cat_incr.display_cond = 'AL' THEN -- FOR nomi IN ( SELECT value FROM (SELECT nnpcv.value ,dense_rank() OVER (ORDER BY nnpcv.gas_day) AS fake_rownum FROM nom_net_point_cat_vals nnpcv WHERE nnpcv.coca_id = cat_incr.coca_id AND nnpcv.conp_id = site_incr.conp_id AND nnpcv.nomi_id = p_nomi_conf_id ORDER BY nnpcv.gas_day) WHERE fake_rownum = date_loop ) LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => nomi.value , p_x_increment => cat_incr.x_incr + l_offset_reduction , p_y_increment => (site_incr.y_incr * l_num_days + (date_loop-1)) ); -- END LOOP; -- ELSE l_offset_reduction := l_offset_reduction - 1; END IF; -- END LOOP; -- END LOOP; -- END LOOP; -- ELSE -- -- Populate cells with zero -- FOR site_incr IN ( SELECT rownum - 1 AS y_incr FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = p_id AND cnp.nepo_id = nepo.nepo_id AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(p_id) = 'Y') OR efno_contracts.emo_contract(p_id) = 'N') ORDER BY nepo.code --cnp.display_sequence ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- FOR cat_incr IN (SELECT rownum - 1 AS x_incr, units FROM (SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,row_number() over (partition by cate.name order by coca.display_sequence) disp_head ,sq1.span ,coca.display_sequence FROM contract_categories coca ,categories cate , (SELECT cate2.name ,count(*) as span FROM contract_categories coca2 ,categories cate2 WHERE coca2.cont_id = p_id AND coca2.cate_id = cate2.cate_id GROUP BY cate2.name) sq1 WHERE cate.cate_id = coca.cate_id AND coca.cont_id = p_id AND sq1.name = cate.name ORDER BY coca.display_sequence ) ) LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => 0 , p_x_increment => cat_incr.x_incr , p_y_increment => (site_incr.y_incr * l_num_days + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END LOOP; -- END IF; -- END IF; -- ELSE -- insert_cell ( p_r_spte => l_r_spte ); -- END IF; -- END LOOP; -- CLOSE cur_spte; -- -- dbms_java.set_output(2000); -- l_conf_type := get_cont_conf_format(p_id); -- IF l_conf_type = 'E' THEN -- l_docu_id := j_writeworkbook( l_spreadsheet_id , 'Nomination' ); -- ELSE -- l_docu_id := p_writeworkbook( l_spreadsheet_id , 'Nomination' ); -- END IF; -- IF p_mode = 'DOWNLOAD' THEN -- -- Initiate the web download -- download(p_docu_id=>l_docu_id); -- ELSIF p_mode = 'INSERT' THEN -- -- direct blob insert into nominations -- UPDATE confirmations conf SET conf.confirmation = ( SELECT docu.blob_content FROM documents docu WHERE docu_id = l_docu_id ) ,conf.conf_file_type = l_conf_type WHERE conf.nomi_id = p_nomi_conf_id AND conf.confirmation_type = 'NO'; -- END IF; -- -- Now remove the document -- DELETE FROM documents d WHERE d.docu_id = l_docu_id; -- ELSE -- NULL; -- END IF; -- EXCEPTION WHEN OTHERS THEN cout_err.report_and_go; END get_template; -- FUNCTION return_conf ( p_conf_id IN confirmations.conf_id%TYPE ) RETURN BLOB IS -- l_return BLOB; -- -- Generic spreadsheet variables -- l_spreadsheet_id gtt_spreadsheet.spreadsheet_id%TYPE; l_docu_id documents.docu_id%TYPE; l_spte_id spreadsheet_templates.spte_id%TYPE; l_cust_id customers.cust_id%TYPE; -- -- Generic value for tag replacement -- l_value VARCHAR2(1000); l_num_days NUMBER; l_offset_reduction NUMBER := 0; -- -- Known tags -- c_cont_placeholder CONSTANT VARCHAR2(100) := '{CONTRACT_ID}'; c_gday_placeholder CONSTANT VARCHAR2(100) := '{GAS_DAY}'; c_cnpcv_placeholder CONSTANT VARCHAR2(100) := '{CONF_NET_POINT_CAT_VALS}'; c_nepo_code CONSTANT VARCHAR2(100) := '{NETWORK_POINT_CODE}'; c_nepo_name CONSTANT VARCHAR2(100) := '{NETWORK_POINT_NAME}'; c_cate_name CONSTANT VARCHAR2(100) := '{CAT_NAME}'; c_cate_units CONSTANT VARCHAR2(100) := '{CAT_UNITS}'; c_cust_name CONSTANT VARCHAR2(100) := '{CUSTOMER_NAME}'; c_cust_email CONSTANT VARCHAR2(100) := '{CUSTOMER_EMAIL}'; c_cust_fax CONSTANT VARCHAR2(100) := '{CUSTOMER_FAX}'; c_nom_gas_day CONSTANT VARCHAR2(100) := '{NOM_GAS_DAY}'; c_nom_timestamp CONSTANT VARCHAR2(100) := '{NOM_TIMESTAMP}'; c_conf_timestamp CONSTANT VARCHAR2(100) := '{CONF_TIMESTAMP}'; -- l_cont_id contracts.cont_id%TYPE; l_conf_gas_day confirmations.gas_day%TYPE; -- l_long_day BOOLEAN; l_short_day BOOLEAN; -- -- Combination cursor - confirmation template and nomination type, it is correct! -- CURSOR cur_spte ( p_spte_id IN spreadsheet_templates.spte_id%TYPE ) IS SELECT l_spreadsheet_id ,sptv.x_axis ,sptv.y_axis ,sptv.cell_value ,sptv.cell_datatype ,sptv.cell_format_mask ,sptv.cell_border ,sptv.cell_background ,sptv.cell_merge ,sptv.cell_font ,sptv.cell_fontsize ,sptv.cell_align ,sptv.col_width ,sptv.row_height ,sptv.cell_wrap ,spte.name FROM spreadsheet_templates spte ,spreadsheet_template_values sptv ,contracts cont WHERE spte.spte_id = cont.spte_id AND cont.cont_id = l_cont_id AND sptv.spte_id = p_spte_id; -- l_r_spte cur_spte%ROWTYPE; -- PROCEDURE insert_cell ( p_r_spte IN cur_spte%ROWTYPE , p_value_overload IN VARCHAR2 DEFAULT NULL , p_x_increment IN NUMBER DEFAULT 0 , p_y_increment IN NUMBER DEFAULT 0 , p_span IN NUMBER DEFAULT NULL ) IS -- l_x_axis VARCHAR2(2) := NULL; -- BEGIN -- IF p_x_increment > 0 THEN -- l_x_axis := CHR(ASCII(p_r_spte.x_axis)+p_x_increment); -- END IF; -- INSERT INTO gtt_spreadsheet ( spreadsheet_id , x_axis , y_axis , cell_value , cell_datatype , cell_format_mask , cell_border , cell_background , cell_merge , cell_font , cell_fontsize , cell_align , col_width , row_height , cell_wrap ) VALUES ( p_r_spte.l_spreadsheet_id , NVL(l_x_axis, p_r_spte.x_axis) , p_r_spte.y_axis + p_y_increment , NVL(p_value_overload, p_r_spte.cell_value) , p_r_spte.cell_datatype , p_r_spte.cell_format_mask , p_r_spte.cell_border , p_r_spte.cell_background , NVL(p_span, p_r_spte.cell_merge) , p_r_spte.cell_font , p_r_spte.cell_fontsize , p_r_spte.cell_align , p_r_spte.col_width , p_r_spte.row_height , p_r_spte.cell_wrap ); -- END insert_cell; -- BEGIN -- -- Get the cont_id from the confirmation -- SELECT NVL(conf.cont_id, nomi.cont_id) AS cont_id ,conf.gas_day INTO l_cont_id ,l_conf_gas_day FROM confirmations conf ,nominations nomi WHERE conf.conf_id = p_conf_id AND conf.nomi_id = nomi.nomi_id (+); -- -- Work out if we need to worry about the long and short days -- l_short_day := FALSE; l_long_day := FALSE; -- -- Check to see if the gas day we are looking at is a long day or a short day -- IF cout_dates.hours_in_gas_day(l_conf_gas_day) = 25 THEN -- l_long_day := TRUE; -- END IF; -- IF cout_dates.hours_in_gas_day(l_conf_gas_day) = 23 THEN -- l_short_day := TRUE; -- END IF; -- -- No specific confirmation formats at the moment, pick the first one returned -- SELECT spte.spte_id INTO l_spte_id FROM spreadsheet_templates spte WHERE spte.spte_type = 'COST' AND ROWNUM < 2; -- -- Get the next sequence value -- SELECT spte_seq.NEXTVAL INTO l_spreadsheet_id FROM DUAL; -- -- Get the cust ID -- SELECT cont.cust_id INTO l_cust_id FROM contracts cont WHERE cont.cont_id = l_cont_id; -- -- Now loop around the template -- OPEN cur_spte ( l_spte_id ); -- LOOP -- FETCH cur_spte INTO l_r_spte; -- EXIT WHEN cur_spte%NOTFOUND; -- IF l_r_spte.cell_value LIKE '{%}' THEN -- -- Candidate for tag replacement, loop through our known tags -- -- {CAT_NAME} -- {CAT_UNITS} -- {CONTRACT_ID} -- {CUSTOMER_NAME} -- {CUSTOMER_EMAIL} -- {CUSTOMER_FAX} -- {GAS_DAY} -- {NETWORK_POINT_CODE} -- {NETWORK_POINT_NAME} -- {CONF_NET_POINT_CAT_VALS} -- l_value := NULL; -- IF l_r_spte.cell_value = c_cont_placeholder THEN -- -- Populate cell with Contract ID -- SELECT cont.contract_number INTO l_value FROM contracts cont WHERE cont.cont_id = l_cont_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_gday_placeholder THEN -- -- Populate cell with Gas Day, just a single value -- --l_start_date := TRUNC(SYSDATE - cout_system_configuration.get_configuration_item('GAS_DAY_OFFSET')/24); -- --l_value := TO_CHAR(l_start_date, efnow098$.g_date_format); -- l_value := TO_CHAR(l_conf_gas_day, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')); -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_nom_gas_day THEN -- -- Populate cell with Nomination Date -- FOR conf_rec IN ( SELECT rownum, nom_gas_day FROM ( SELECT nepo.name --cnp.display_sequence , conf.gas_day , NVL(TO_CHAR(MIN(NVL(last_gas_day, DECODE(sq1.defaulted, 'Y', NULL, conf.gas_day))),cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),' ') AS nom_gas_day FROM conf_net_point_cat_vals conf ,nominations nomi ,cont_network_points cnp ,confirmations cnf ,network_points nepo ,(SELECT MAX(conf2.defaulted) as DEFAULTED , conp_id FROM conf_net_point_cat_vals conf2 WHERE conf2.conf_id = p_conf_id GROUP BY conp_id ) sq1 WHERE nomi.nomi_id (+) = conf.nomi_id AND cnp.nepo_id = nepo.nepo_id AND conf.conf_id = p_conf_id AND cnf.conf_id = p_conf_id AND cnp.conp_id = conf.conp_id AND conf.conp_id = sq1.conp_id GROUP BY nepo.name --cnp.display_sequence , conf.gas_day ORDER BY gas_day ) ) LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => conf_rec.nom_gas_day , p_y_increment => conf_rec.rownum -1 ); -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_nom_timestamp THEN -- -- Populate cell with Nomination Timestamp -- FOR conf_rec IN ( SELECT rownum, nom_timestamp FROM ( SELECT nepo.name --cnp.display_sequence , conf.gas_day , DECODE(sq1.defaulted, 'Y', ' ', NVL(TO_CHAR(NVL(cnf.confirmation_sent, conf.last_nom_received),cout_system_configuration.get_configuration_item('G_DATE_FORMAT')||' HH24:MI'),' ')) AS nom_timestamp FROM conf_net_point_cat_vals conf ,nominations nomi ,cont_network_points cnp ,network_points nepo ,confirmations cnf ,confirmations cnf2 ,(SELECT MAX(conf2.defaulted) as DEFAULTED , conp_id FROM conf_net_point_cat_vals conf2 WHERE conf2.conf_id = p_conf_id GROUP BY conp_id ) sq1 WHERE nomi.nomi_id (+) = conf.nomi_id AND conf.conf_id = p_conf_id AND cnf.nomi_id (+) = NVL(conf.last_nomi_id, conf.nomi_id) AND cnf.confirmation_type(+) = 'NO' AND cnf2.conf_id = conf.conf_id AND cnf2.confirmation_type = 'CO' AND cnp.conp_id = conf.conp_id AND cnp.nepo_id = nepo.nepo_id AND sq1.conp_id = conf.conp_id GROUP BY nepo.name --cnp.display_sequence , conf.gas_day, DECODE(sq1.defaulted, 'Y', ' ' , NVL(TO_CHAR(NVL(cnf.confirmation_sent, conf.last_nom_received),cout_system_configuration.get_configuration_item('G_DATE_FORMAT')||' HH24:MI'),' ')) ORDER BY gas_day ) ) LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => conf_rec.nom_timestamp , p_y_increment => conf_rec.rownum -1 ); -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_conf_timestamp THEN -- -- Populate cell with Confirmation Timestamp -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => caco_utilities.get_module_text(3568)||': '||TO_CHAR(SYSDATE, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')||' HH24:MI:SS') ); -- END IF; -- IF l_r_spte.cell_value = c_cust_name THEN -- -- Populate cell with Customer Name -- SELECT cust.name INTO l_value FROM contracts cont ,customers cust WHERE cont.cont_id = l_cont_id AND cont.cust_id = cust.cust_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_cust_email THEN -- -- Populate cell with Customer Email -- SELECT cust.email_address INTO l_value FROM contracts cont ,customers cust WHERE cont.cont_id = l_cont_id AND cont.cust_id = cust.cust_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_cust_fax THEN -- -- Populate cell with Customer Fax -- SELECT cust.fax INTO l_value FROM contracts cont ,customers cust WHERE cont.cont_id = l_cont_id AND cont.cust_id = cust.cust_id; -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => l_value ); -- END IF; -- IF l_r_spte.cell_value = c_nepo_code THEN -- -- Populate cell with Network Point Code -- l_num_days := 1; -- FOR site_rec IN ( SELECT site ,rownum FROM ( SELECT nepo.code AS site FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = l_cont_id AND nepo.nepo_id = cnp.nepo_id ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => site_rec.site , p_y_increment => ((site_rec.rownum - 1) * l_num_days + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_nepo_name THEN -- -- Populate cell with Network Point Name -- -- IF UPPER(l_r_spte.name) = UPPER(efnow098$.g_spte_single) THEN -- -- l_num_days := 1; -- -- --ELSE -- -- -- l_num_days := cout_system_configuration.get_configuration_item('G_MULTI_DAY_NOM_DAYS'); -- -- --END IF; -- FOR site_rec IN ( SELECT site ,rownum FROM ( SELECT nepo.name AS site FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = l_cont_id AND nepo.nepo_id = cnp.nepo_id ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => site_rec.site , p_y_increment => ((site_rec.rownum - 1) * l_num_days + (date_loop-1)) ); -- END LOOP; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_cate_name THEN -- -- Populate cell with Category Name -- FOR cat IN (SELECT rownum, code, name, units, display_cond, disp_head, span, sum(last_span) OVER (order by display_sequence) AS running_offset FROM (SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,row_number() over (partition by cate.name order by coca.display_sequence) disp_head ,sq1.span ,lag(span,1,0) OVER (ORDER BY coca.display_sequence) AS last_span ,coca.display_sequence FROM contract_categories coca ,categories cate , (SELECT cate2.name ,count(*) as span FROM contract_categories coca2 ,categories cate2 WHERE coca2.cont_id = l_cont_id AND coca2.cate_id = cate2.cate_id GROUP BY cate2.name) sq1 WHERE cate.cate_id = coca.cate_id AND coca.cont_id = l_cont_id AND sq1.name = cate.name ORDER BY coca.display_sequence ) ) LOOP -- IF (cat.display_cond = 'LO' AND l_long_day) OR (cat.display_cond = 'SH' AND NOT l_short_day) OR cat.display_cond = 'AL' THEN -- IF cat.disp_head = 1 THEN -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => cat.name , p_x_increment => l_offset_reduction , p_span => cat.span -1 ); -- l_offset_reduction := l_offset_reduction + cat.span; -- END IF; -- END IF; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_cate_units THEN -- -- Populate cell with Category Units -- FOR cat IN (SELECT rownum, units, display_cond FROM (SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,row_number() over (partition by cate.name order by coca.display_sequence) disp_head ,sq1.span ,coca.display_sequence FROM contract_categories coca ,categories cate , (SELECT cate2.name ,count(*) as span FROM contract_categories coca2 ,categories cate2 WHERE coca2.cont_id = l_cont_id AND coca2.cate_id = cate2.cate_id GROUP BY cate2.name) sq1 WHERE cate.cate_id = coca.cate_id AND coca.cont_id = l_cont_id AND sq1.name = cate.name ORDER BY coca.display_sequence ) ) LOOP -- IF (cat.display_cond = 'LO' AND l_long_day) OR (cat.display_cond = 'SH' AND NOT l_short_day) OR cat.display_cond = 'AL' THEN -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => cat.units , p_x_increment => cat.rownum - 1 ); -- END IF; -- END LOOP; -- END IF; -- IF l_r_spte.cell_value = c_cnpcv_placeholder THEN -- -- Check for multi or single gas days -- IF UPPER(l_r_spte.name) IN (UPPER(g_spte_single),UPPER(g_spte_smulti)) THEN -- l_num_days := 1; -- ELSE -- --l_num_days := cout_system_configuration.get_configuration_item('G_MULTI_DAY_NOM_DAYS'); l_num_days := 1; -- END IF; -- -- Populate cell with Network Point Values, if required -- IF p_conf_id IS NOT NULL THEN -- -- Populate cells with nomination -- FOR site_incr IN ( SELECT rownum - 1 AS y_incr ,conp_id FROM (SELECT cnp.conp_id FROM cont_network_points cnp ,network_points nepo WHERE cnp.cont_id = l_cont_id AND cnp.nepo_id = nepo.nepo_id ORDER BY nepo.code --cnp.display_sequence ) ) LOOP -- FOR date_loop IN 1..l_num_days LOOP -- FOR cat_incr IN (SELECT rownum - 1 AS x_incr, units, display_cond, coca_id FROM (SELECT coca.coca_id ,cate.code ,cate.name ,cate.units ,cate.display_cond ,row_number() over (partition by cate.name order by coca.display_sequence) disp_head ,sq1.span ,coca.display_sequence FROM contract_categories coca ,categories cate , (SELECT cate2.name ,count(*) as span FROM contract_categories coca2 ,categories cate2 WHERE coca2.cont_id = l_cont_id AND coca2.cate_id = cate2.cate_id GROUP BY cate2.name) sq1 WHERE cate.cate_id = coca.cate_id AND coca.cont_id = l_cont_id AND sq1.name = cate.name ORDER BY coca.display_sequence ) ) LOOP -- FOR conf IN ( SELECT value, interrupted FROM (SELECT cnpcv.value, cnpcv.interrupted ,dense_rank() OVER (ORDER BY cnpcv.gas_day) AS fake_rownum FROM conf_net_point_cat_vals cnpcv WHERE cnpcv.coca_id = cat_incr.coca_id AND cnpcv.conp_id = site_incr.conp_id AND cnpcv.conf_id = p_conf_id ORDER BY cnpcv.gas_day) WHERE fake_rownum = date_loop ) LOOP -- IF conf.interrupted = 'Y' THEN -- l_r_spte.cell_background := 'RED'; -- ELSE -- l_r_spte.cell_background := NULL; -- END IF; -- IF (cat_incr.display_cond = 'LO' AND l_long_day) OR (cat_incr.display_cond = 'SH' AND NOT l_short_day) OR cat_incr.display_cond = 'AL' THEN -- insert_cell ( p_r_spte => l_r_spte , p_value_overload => conf.value , p_x_increment => cat_incr.x_incr , p_y_increment => (site_incr.y_incr * l_num_days + (date_loop-1)) ); -- END IF; -- END LOOP; -- END LOOP; -- END LOOP; -- END LOOP; -- END IF; -- END IF; -- ELSE -- insert_cell ( p_r_spte => l_r_spte ); -- END IF; -- END LOOP; -- CLOSE cur_spte; -- -- dbms_java.set_output(2000); -- IF get_cont_conf_format(l_cont_id) = 'E' THEN -- l_docu_id := j_writeworkbook( l_spreadsheet_id , TO_CHAR(l_conf_gas_day, 'YYYY.MM.DD') --caco_utilities.get_module_text(2072) ); -- ELSE -- l_docu_id := p_writeworkbook( l_spreadsheet_id , TO_CHAR(l_conf_gas_day, 'YYYY.MM.DD') --caco_utilities.get_module_text(2072) ); -- END IF; -- -- Get the document into the return variable -- SELECT docu.blob_content INTO l_return FROM documents docu WHERE docu_id = l_docu_id; -- -- Now remove the document -- DELETE FROM documents d WHERE d.docu_id = l_docu_id; -- -- And return -- RETURN l_return; -- EXCEPTION WHEN OTHERS THEN caco_debug.putline('error in amfr_excel: '||sqlcode||' '||sqlerrm||' '||dbms_utility.format_error_backtrace); cout_err.report_and_go(p_exception_number => sqlcode, p_exception_message => sqlerrm); END return_conf; /* DECLARE l_num NUMBER; BEGIN -- Call the function dbms_java.set_output(2000); :RESULT := amfr_excel.j_readworkbook(p_docu_id => :p_docu_id); SELECT COUNT(*) INTO l_num FROM gtt_spreadsheet; htp.p(l_num); INSERT INTO spreadsheet_template_values (spte_id ,NAME ,x_axis ,y_axis ,cell_value ,cell_background) (SELECT :spte_id ,'cell?' ,gs.x_axis ,gs.y_axis ,gs.cell_value ,gs.cell_background FROM gtt_spreadsheet gs); END; */ /* update spreadsheet_template_values set cell_background='AQUA' where cell_background='49'; update spreadsheet_template_values set cell_background='BLACK' where cell_background='8'; update spreadsheet_template_values set cell_background='BLUE' where cell_background='12'; update spreadsheet_template_values set cell_background='BLUE_GREY' where cell_background='54'; update spreadsheet_template_values set cell_background='BRIGHT_GREEN' where cell_background='11'; update spreadsheet_template_values set cell_background='BROWN' where cell_background='60'; update spreadsheet_template_values set cell_background='CORAL' where cell_background='29'; update spreadsheet_template_values set cell_background='CORNFLOWER_BLUE' where cell_background='24'; update spreadsheet_template_values set cell_background='DARK_BLUE' where cell_background='18'; update spreadsheet_template_values set cell_background='DARK_GREEN' where cell_background='58'; update spreadsheet_template_values set cell_background='DARK_RED' where cell_background='16'; update spreadsheet_template_values set cell_background='DARK_TEAL' where cell_background='56'; update spreadsheet_template_values set cell_background='DARK_YELLOW' where cell_background='19'; update spreadsheet_template_values set cell_background='GOLD' where cell_background='51'; update spreadsheet_template_values set cell_background='GREEN' where cell_background='17'; update spreadsheet_template_values set cell_background='GREY_25_PERCENT' where cell_background='22'; update spreadsheet_template_values set cell_background='GREY_40_PERCENT' where cell_background='55'; update spreadsheet_template_values set cell_background='GREY_50_PERCENT' where cell_background='23'; update spreadsheet_template_values set cell_background='GREY_80_PERCENT' where cell_background='63'; update spreadsheet_template_values set cell_background='INDIGO' where cell_background='62'; update spreadsheet_template_values set cell_background='LAVENDER' where cell_background='46'; update spreadsheet_template_values set cell_background='LEMON_CHIFFON' where cell_background='26'; update spreadsheet_template_values set cell_background='LIGHT_BLUE' where cell_background='48'; update spreadsheet_template_values set cell_background='LIGHT_CORNFLOWER_BLUE' where cell_background='31'; update spreadsheet_template_values set cell_background='LIGHT_GREEN' where cell_background='42'; update spreadsheet_template_values set cell_background='LIGHT_ORANGE' where cell_background='52'; update spreadsheet_template_values set cell_background='LIGHT_TURQUOISE' where cell_background='41'; update spreadsheet_template_values set cell_background='LIGHT_YELLOW' where cell_background='43'; update spreadsheet_template_values set cell_background='LIME' where cell_background='50'; update spreadsheet_template_values set cell_background='MAROON' where cell_background='25'; update spreadsheet_template_values set cell_background='OLIVE_GREEN' where cell_background='59'; update spreadsheet_template_values set cell_background='ORANGE' where cell_background='53'; update spreadsheet_template_values set cell_background='ORCHID' where cell_background='28'; update spreadsheet_template_values set cell_background='PALE_BLUE' where cell_background='44'; update spreadsheet_template_values set cell_background='PINK' where cell_background='14'; update spreadsheet_template_values set cell_background='PLUM' where cell_background='61'; update spreadsheet_template_values set cell_background='RED' where cell_background='10'; update spreadsheet_template_values set cell_background='ROSE' where cell_background='45'; update spreadsheet_template_values set cell_background='ROYAL_BLUE' where cell_background='30'; update spreadsheet_template_values set cell_background='SEA_GREEN' where cell_background='57'; update spreadsheet_template_values set cell_background='SKY_BLUE' where cell_background='40'; update spreadsheet_template_values set cell_background='TAN' where cell_background='47'; update spreadsheet_template_values set cell_background='TEAL' where cell_background='21'; update spreadsheet_template_values set cell_background='TURQUOISE' where cell_background='15'; update spreadsheet_template_values set cell_background='VIOLET' where cell_background='20'; update spreadsheet_template_values set cell_background='WHITE' where cell_background='9'; update spreadsheet_template_values set cell_background='YELLOW' where cell_background='13'; update spreadsheet_template_values set cell_background='WHITE' where cell_background='9'; update spreadsheet_template_values set cell_background=NULL where cell_background='64'; */ -- FUNCTION about RETURN VARCHAR2 IS BEGIN -- RETURN(g_package_name || CHR(10) || g_revision || CHR(10) || g_header); -- END about; -- BEGIN /** -- Initialization */ NULL; -- END amfr_excel; /