909 lines
36 KiB
Plaintext
909 lines
36 KiB
Plaintext
CREATE OR REPLACE PACKAGE BODY efno_interruption IS
|
|
--
|
|
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';
|
|
--
|
|
PROCEDURE replace_text_tags( p_int_id IN interruptions.int_id%TYPE
|
|
, p_cust_id IN customers.cust_id%TYPE DEFAULT NULL
|
|
, p_text IN OUT VARCHAR2
|
|
) IS
|
|
--
|
|
c_cust_name CONSTANT VARCHAR2(100) := '{CUSTOMER_NAME}';
|
|
c_start_date CONSTANT VARCHAR2(100) := '{START_DATE}';
|
|
c_end_date CONSTANT VARCHAR2(100) := '{END_DATE}';
|
|
--
|
|
CURSOR cur_int ( p_int_id IN interruptions.int_id%TYPE ) IS
|
|
SELECT int.gas_day_start
|
|
,int.gas_day_end
|
|
FROM interruptions int
|
|
WHERE int.int_id = p_int_id;
|
|
--
|
|
lr_interruption cur_int%ROWTYPE;
|
|
--
|
|
BEGIN
|
|
--
|
|
OPEN cur_int ( p_int_id => p_int_id );
|
|
FETCH cur_int
|
|
INTO lr_interruption;
|
|
CLOSE cur_int;
|
|
--
|
|
p_text := REPLACE(p_text, c_cust_name, caco_utilities.get_cust_name(p_cust_id));
|
|
p_text := REPLACE(p_text, c_start_date, TO_CHAR(lr_interruption.gas_day_start, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')));
|
|
p_text := REPLACE(p_text, c_end_date, NVL(TO_CHAR(lr_interruption.gas_day_end, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),' '));
|
|
--
|
|
END replace_text_tags;
|
|
--
|
|
--
|
|
--
|
|
FUNCTION return_int_ss ( p_int_id IN interruptions.int_id%TYPE
|
|
, p_cont_id IN contracts.cont_id%TYPE
|
|
) RETURN BLOB IS
|
|
--
|
|
--
|
|
--
|
|
c_spte_id CONSTANT spreadsheet_templates.spte_id%TYPE := 90;
|
|
--
|
|
-- Generated Document
|
|
--
|
|
l_return BLOB;
|
|
--
|
|
-- Generic spreadsheet variables
|
|
--
|
|
l_spreadsheet_id gtt_spreadsheet.spreadsheet_id%TYPE;
|
|
l_docu_id documents.docu_id%TYPE;
|
|
l_cust_id customers.cust_id%TYPE;
|
|
--
|
|
-- Generic value for tag replacement
|
|
--
|
|
l_value VARCHAR2(1000);
|
|
l_start_date DATE;
|
|
l_num_days NUMBER;
|
|
l_offset_reduction NUMBER := 0;
|
|
--
|
|
-- Known tags
|
|
--
|
|
c_cust_name CONSTANT VARCHAR2(100) := '{CUSTOMER_NAME}';
|
|
c_cont_name CONSTANT VARCHAR2(100) := '{CONTRACT_NAME}';
|
|
c_start_date CONSTANT VARCHAR2(100) := '{START_DATE}';
|
|
c_end_date CONSTANT VARCHAR2(100) := '{END_DATE}';
|
|
c_nepo_code CONSTANT VARCHAR2(100) := '{NETWORK_POINT_CODE}';
|
|
c_nepo_name CONSTANT VARCHAR2(100) := '{NETWORK_POINT_NAME}';
|
|
c_cate_name CONSTANT VARCHAR2(100) := '{CATE_NAME}';
|
|
c_cate_units CONSTANT VARCHAR2(100) := '{CATE_UNITS}';
|
|
c_iccv_placeholder CONSTANT VARCHAR2(100) := '{INT_CONT_CAT_VALS}';
|
|
--
|
|
-- 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
|
|
WHERE spte.spte_id = sptv.spte_id
|
|
AND sptv.spte_id = c_spte_id;
|
|
--
|
|
l_r_spte cur_spte%ROWTYPE;
|
|
--
|
|
CURSOR cur_int (p_int_id IN interruptions.int_id%TYPE) IS
|
|
SELECT int.*
|
|
FROM interruptions int
|
|
WHERE int.int_id = p_int_id;
|
|
--
|
|
lr_int cur_int%ROWTYPE;
|
|
--
|
|
CURSOR cur_grid ( p_int_id IN interruptions.int_id%TYPE ) IS
|
|
SELECT iccv.iccv_id
|
|
, cust.code cust
|
|
, iccv.conp_id
|
|
, coca.cate_id
|
|
, iccv.send_to_customer
|
|
, iccv.contracted_value
|
|
, iccv.interrupted_value
|
|
, iccv.confirmed_value
|
|
,nepo.name||':'||cust.name neponame
|
|
,ROW_NUMBER() OVER (PARTITION BY cate.name ORDER BY cust.code NULLS LAST) grid_row
|
|
FROM int_conp_coca_vals iccv
|
|
,contract_categories coca
|
|
,categories cate
|
|
,cont_network_points conp
|
|
,network_points nepo
|
|
,contracts cont
|
|
,customers cust
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND coca.cate_id = cate.cate_id
|
|
AND iccv.conp_id = conp.conp_id
|
|
AND coca.cont_id = cont.cont_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND cont.cust_id = cust.cust_id
|
|
AND cont.cont_id = p_cont_id
|
|
ORDER BY cust.code
|
|
,nepo.code
|
|
,cate.display_sequence;
|
|
--
|
|
lr_grid_row cur_grid%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 details from interruptions
|
|
--
|
|
OPEN cur_int(p_int_id => p_int_id);
|
|
FETCH cur_int
|
|
INTO lr_int;
|
|
CLOSE cur_int;
|
|
--
|
|
--
|
|
-- 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 = p_cont_id;
|
|
--
|
|
-- Now loop around the template
|
|
--
|
|
OPEN cur_spte ( c_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}
|
|
-- {CONTRACT_NAME}
|
|
-- {CUSTOMER_EMAIL}
|
|
-- {CUSTOMER_FAX}
|
|
-- {GAS_DAY}
|
|
-- {NETWORK_POINT_CODE}
|
|
-- {NETWORK_POINT_NAME}
|
|
-- {INT_CONT_CAT_VALS}
|
|
--
|
|
l_value := NULL;
|
|
--
|
|
IF INSTR(l_r_spte.cell_value, c_cust_name) > 0 THEN
|
|
--
|
|
SELECT cust.name
|
|
INTO l_value
|
|
FROM customers cust
|
|
,contracts cont
|
|
WHERE cont.cust_id = cust.cust_id
|
|
AND cont.cont_id = p_cont_id;
|
|
--
|
|
l_value := REPLACE(l_r_spte.cell_value, c_cust_name, l_value);
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => l_value
|
|
);
|
|
--
|
|
END IF;
|
|
--
|
|
IF INSTR(l_r_spte.cell_value, c_cont_name) > 0 THEN
|
|
--
|
|
SELECT cont.contract_number
|
|
INTO l_value
|
|
FROM customers cust
|
|
,contracts cont
|
|
WHERE cont.cust_id = cust.cust_id
|
|
AND cont.cont_id = p_cont_id;
|
|
--
|
|
l_value := REPLACE(l_r_spte.cell_value, c_cont_name, l_value);
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => l_value
|
|
);
|
|
--
|
|
END IF;
|
|
--
|
|
IF INSTR(l_r_spte.cell_value, c_start_date) > 0 OR INSTR(l_r_spte.cell_value, c_end_date) > 0 THEN
|
|
--
|
|
l_value := l_r_spte.cell_value;
|
|
--
|
|
l_value := REPLACE(l_value, c_start_date, NVL(TO_CHAR( lr_int.gas_day_start, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),''));
|
|
l_value := REPLACE(l_value, c_end_date, NVL(TO_CHAR( lr_int.gas_day_end, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),''));
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => l_value
|
|
);
|
|
--
|
|
--
|
|
ELSIF INSTR(l_r_spte.cell_value, c_start_date) > 0 THEN
|
|
--
|
|
l_value := NVL(TO_CHAR( lr_int.gas_day_start, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),'');
|
|
--
|
|
l_value := REPLACE(l_r_spte.cell_value, c_start_date, l_value);
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => l_value
|
|
);
|
|
--
|
|
ELSIF INSTR(l_r_spte.cell_value, c_end_date) > 0 THEN
|
|
--
|
|
l_value := NVL(TO_CHAR( lr_int.gas_day_end, cout_system_configuration.get_configuration_item('G_DATE_FORMAT')),'');
|
|
--
|
|
l_value := REPLACE(l_r_spte.cell_value, c_end_date, l_value);
|
|
--
|
|
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
|
|
--
|
|
FOR site_rec IN ( SELECT site
|
|
,rownum FROM (
|
|
SELECT nepo.code AS site
|
|
FROM int_conp_coca_vals int
|
|
,cont_network_points conp
|
|
,network_points nepo
|
|
WHERE int.int_id = p_int_id
|
|
AND int.conp_id = conp.conp_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND conp.cont_id = p_cont_id
|
|
GROUP BY nepo.code
|
|
ORDER BY nepo.code
|
|
)
|
|
) LOOP
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => site_rec.site
|
|
, p_y_increment => (site_rec.rownum - 1)
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_r_spte.cell_value = c_nepo_name THEN
|
|
--
|
|
FOR site_rec IN ( SELECT site
|
|
,rownum FROM (
|
|
SELECT nepo.name AS site
|
|
FROM int_conp_coca_vals int
|
|
,cont_network_points conp
|
|
,network_points nepo
|
|
WHERE int.int_id = p_int_id
|
|
AND int.conp_id = conp.conp_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND conp.cont_id = p_cont_id
|
|
GROUP BY nepo.name
|
|
,nepo.code
|
|
ORDER BY nepo.code
|
|
)
|
|
) LOOP
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => site_rec.site
|
|
, p_y_increment => (site_rec.rownum - 1)
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_r_spte.cell_value = c_cate_name THEN
|
|
--
|
|
-- Populate cell with Category Name
|
|
--
|
|
FOR cat IN ( SELECT rownum, cate_id, name FROM (SELECT coca.cate_id
|
|
, cate.name
|
|
, cate.display_sequence
|
|
FROM int_conp_coca_vals iccv
|
|
,contract_categories coca
|
|
,categories cate
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND coca.cate_id = cate.cate_id
|
|
GROUP BY coca.cate_id
|
|
, cate.name
|
|
, cate.display_sequence
|
|
ORDER BY cate.display_sequence
|
|
)) LOOP
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => cat.name
|
|
, p_x_increment => cat.rownum - 1
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_r_spte.cell_value = c_cate_units THEN
|
|
--
|
|
-- Populate cell with Category Units
|
|
--
|
|
FOR cat IN ( SELECT rownum, cate_id, name, units FROM (SELECT coca.cate_id
|
|
, cate.name
|
|
, cate.units
|
|
, cate.display_sequence
|
|
FROM int_conp_coca_vals iccv
|
|
,contract_categories coca
|
|
,categories cate
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND coca.cate_id = cate.cate_id
|
|
GROUP BY coca.cate_id
|
|
, cate.name
|
|
, cate.units
|
|
, cate.display_sequence
|
|
ORDER BY cate.display_sequence
|
|
)) LOOP
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => cat.units
|
|
, p_x_increment => cat.rownum - 1
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_r_spte.cell_value = c_iccv_placeholder THEN
|
|
--
|
|
OPEN cur_grid(p_int_id => p_int_id);
|
|
FETCH cur_grid
|
|
INTO lr_grid_row;
|
|
--
|
|
FOR custnepo IN ( SELECT rownum-1 AS yincr
|
|
,sq.* FROM (
|
|
SELECT cust.code cust
|
|
, nepo.code nepo
|
|
, nepo.name neponame
|
|
, iccv.conp_id conp
|
|
FROM int_conp_coca_vals iccv
|
|
,cont_network_points conp
|
|
,network_points nepo
|
|
,contracts cont
|
|
,customers cust
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.conp_id = conp.conp_id
|
|
AND conp.cont_id = cont.cont_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND cont.cust_id = cust.cust_id
|
|
AND cont.cont_id = p_cont_id
|
|
GROUP BY cust.code
|
|
, nepo.code
|
|
, nepo.name
|
|
, iccv.conp_id
|
|
ORDER BY cust.code
|
|
,nepo.code ) sq ) LOOP
|
|
--
|
|
FOR griddetail IN (SELECT rownum-1 AS xincr, cate_id, name, inty_code FROM (
|
|
SELECT coca.cate_id
|
|
, cate.name
|
|
, cate.display_sequence
|
|
, inty.code AS inty_code
|
|
FROM int_conp_coca_vals iccv
|
|
,contract_categories coca
|
|
,categories cate
|
|
,interruption_types inty
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND coca.cate_id = cate.cate_id
|
|
AND inty.cate_id (+) = cate.cate_id
|
|
AND inty.status (+) = 'A'
|
|
GROUP BY coca.cate_id
|
|
, cate.name
|
|
, cate.display_sequence
|
|
, inty.code
|
|
ORDER BY cate.display_sequence
|
|
)) LOOP
|
|
--
|
|
-- fetch cursor
|
|
--
|
|
IF lr_grid_row.cate_id = griddetail.cate_id
|
|
AND lr_grid_row.conp_id = custnepo.conp THEN
|
|
--
|
|
IF lr_grid_row.send_to_customer = 'Y' THEN
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => caco_utilities.to_thousand_separated(lr_grid_row.interrupted_value)
|
|
, p_x_increment => griddetail.xincr
|
|
, p_y_increment => custnepo.yincr
|
|
);
|
|
ELSE
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
, p_value_overload => caco_utilities.to_thousand_separated(lr_grid_row.contracted_value)
|
|
, p_x_increment => griddetail.xincr
|
|
, p_y_increment => custnepo.yincr
|
|
);
|
|
|
|
END IF;
|
|
--
|
|
FETCH cur_grid
|
|
INTO lr_grid_row;
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP; --cate
|
|
--
|
|
END LOOP;--custnepo
|
|
--
|
|
CLOSE cur_grid;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
insert_cell ( p_r_spte => l_r_spte
|
|
);
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP;
|
|
--
|
|
CLOSE cur_spte;
|
|
--
|
|
-- dbms_java.set_output(2000);
|
|
--
|
|
l_docu_id := j_writeworkbook( l_spreadsheet_id
|
|
, caco_utilities.get_module_text(p_text_number => 3803)
|
|
);
|
|
--
|
|
-- 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
|
|
cout_err.report_and_go(p_exception_number => sqlcode, p_exception_message => sqlerrm);
|
|
END return_int_ss;
|
|
--
|
|
PROCEDURE download ( p_remd_id IN rec_message_details.remd_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 remd.message_attachment
|
|
INTO l_document_contents
|
|
FROM rec_message_details remd
|
|
WHERE remd.remd_id = p_remd_id;
|
|
--
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
--
|
|
NULL;
|
|
--
|
|
END;
|
|
--
|
|
l_document_name := caco_utilities.get_module_text(3803)||'.xls';
|
|
l_mime_type := 'application/vnd.ms-excel';
|
|
--
|
|
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_global( p_var IN VARCHAR2 ) RETURN VARCHAR2 IS
|
|
--
|
|
l_return VARCHAR2(30);
|
|
--
|
|
BEGIN
|
|
--
|
|
IF p_var = 'g_query_id' THEN
|
|
--
|
|
l_return := g_query_id;
|
|
--
|
|
ELSIF p_var = 'g_query_start' THEN
|
|
--
|
|
l_return := g_query_start;
|
|
--
|
|
ELSIF p_var = 'g_query_end' THEN
|
|
--
|
|
l_return := g_query_end;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_return;
|
|
--
|
|
END get_global;
|
|
--
|
|
PROCEDURE send_messages ( p_int_id IN interruptions.int_id%TYPE DEFAULT NULL
|
|
) IS
|
|
--
|
|
v_substitution_list caco_utilities.g_t_substitution_list;
|
|
--
|
|
CURSOR cur_cust (p_cust_id IN customers.cust_id%TYPE ) IS
|
|
SELECT cust.int_subject
|
|
,cust.int_content
|
|
,cust.int_sms_content
|
|
FROM customers cust
|
|
WHERE cust.cust_id = p_cust_id;
|
|
--
|
|
lr_cust_rec cur_cust%ROWTYPE;
|
|
--
|
|
l_intr_ss BLOB;
|
|
--
|
|
BEGIN
|
|
--
|
|
-- security check - check for access to base package
|
|
--
|
|
IF NOT caco_security.security_check('efnow210$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
IF p_int_id IS NOT NULL THEN
|
|
--
|
|
-- loop around all distinct recipients
|
|
--
|
|
FOR cust_rec IN ( SELECT cont.cust_id
|
|
,cont.cont_id
|
|
FROM int_conp_coca_vals iccv
|
|
, cont_network_points conp
|
|
, contracts cont
|
|
WHERE iccv.int_id = p_int_id
|
|
AND iccv.conp_id = conp.conp_id
|
|
AND conp.cont_id = cont.cont_id
|
|
AND iccv.send_to_customer = 'Y'
|
|
GROUP BY cont.cust_id
|
|
, cont.cont_id
|
|
) LOOP
|
|
--
|
|
-- Get static details
|
|
--
|
|
OPEN cur_cust ( cust_rec.cust_id );
|
|
FETCH cur_cust
|
|
INTO lr_cust_rec;
|
|
CLOSE cur_cust;
|
|
--
|
|
-- Sustitute any tags
|
|
--
|
|
replace_text_tags( p_int_id => p_int_id
|
|
, p_cust_id => cust_rec.cust_id
|
|
, p_text => lr_cust_rec.int_content
|
|
);
|
|
--
|
|
-- Generate details to be sent
|
|
--
|
|
l_intr_ss := return_int_ss ( p_int_id => p_int_id
|
|
, p_cont_id => cust_rec.cont_id
|
|
);
|
|
--
|
|
-- Now send the details
|
|
--
|
|
efno_msgsubs.send_recorded_messages( p_cust_id => cust_rec.cust_id
|
|
, p_suca_id => efno_msgsubs.get_suca_id( p_suca_group => 'Notification'
|
|
, p_suca_name => 'Commercial' )
|
|
, p_message_type => 'Interruption'
|
|
, p_message_id => p_int_id
|
|
, p_email_content_en => lr_cust_rec.int_content
|
|
, p_email_subject_en => lr_cust_rec.int_subject
|
|
, p_sms_content_en => lr_cust_rec.int_sms_content
|
|
, p_file => l_intr_ss
|
|
, p_filename => caco_utilities.get_module_text(3803)||'.xls'
|
|
, p_file_mime_type => 'application/vnd.ms-excel'
|
|
);
|
|
--
|
|
END LOOP; -- cust_rec
|
|
--
|
|
ELSE
|
|
--
|
|
v_substitution_list(1) := 'p_int_id';
|
|
--
|
|
caco_utilities.raise_exception_error( p_exception_number => -20100
|
|
, p_substitution_list => v_substitution_list
|
|
);
|
|
--
|
|
END IF;
|
|
--
|
|
END send_messages;
|
|
--
|
|
--
|
|
--
|
|
FUNCTION get_int_val ( p_val IN NUMBER
|
|
, p_conp_id IN NUMBER
|
|
, p_copa_id IN NUMBER
|
|
, p_gasday IN DATE
|
|
) RETURN NUMBER IS
|
|
--
|
|
l_return NUMBER;
|
|
--
|
|
BEGIN
|
|
--
|
|
l_return := p_val;
|
|
--
|
|
FOR int IN (SELECT int.int_id
|
|
FROM interruptions int
|
|
WHERE p_gasday BETWEEN int.gas_day_start AND NVL(int.gas_day_end, p_gasday)
|
|
) LOOP
|
|
--
|
|
-- Interruption is in place on this gas day, check if value is reduced
|
|
--
|
|
FOR iccv IN ( SELECT iccv.interrupted_value AS value
|
|
FROM int_conp_coca_vals iccv
|
|
,contract_categories coca
|
|
,parameters pars
|
|
,contract_parameters copa
|
|
WHERE iccv.int_id = int.int_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND coca.cate_id = pars.cate_id
|
|
AND pars.pars_id = copa.pars_id
|
|
AND copa.cont_id = coca.cont_id
|
|
AND iccv.conp_id = p_conp_id
|
|
AND copa.copa_id = p_copa_id
|
|
AND iccv.send_to_customer = 'Y'
|
|
AND (pars.code LIKE '%MAX'
|
|
OR pars.code LIKE '%CTR')
|
|
) LOOP
|
|
--
|
|
-- Only substitue MAX and contracted, and only if the interrupted value is lower
|
|
--
|
|
l_return := LEAST(iccv.value, l_return);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END LOOP;
|
|
--
|
|
RETURN l_return;
|
|
--
|
|
END get_int_val;
|
|
--
|
|
FUNCTION am_i_interrrupted ( p_conp_id IN cont_network_points.conp_id%TYPE
|
|
, p_coca_id IN contract_categories.coca_id%TYPE
|
|
, p_gasday IN DATE
|
|
) RETURN BOOLEAN IS
|
|
--
|
|
l_return BOOLEAN := FALSE;
|
|
--
|
|
BEGIN
|
|
--
|
|
FOR int IN (SELECT int.int_id
|
|
FROM interruptions int
|
|
WHERE p_gasday BETWEEN int.gas_day_start AND NVL(int.gas_day_end, p_gasday)
|
|
) LOOP
|
|
--
|
|
-- Interruption is in place on this gas day, check if value is reduced
|
|
--
|
|
FOR iccv IN ( SELECT iccv.interrupted_value AS int_val
|
|
,iccv.contracted_value AS cont_val
|
|
FROM int_conp_coca_vals iccv
|
|
WHERE iccv.int_id = int.int_id
|
|
AND iccv.coca_id = p_coca_id
|
|
AND iccv.conp_id = p_conp_id
|
|
AND iccv.send_to_customer = 'Y'
|
|
) LOOP
|
|
--
|
|
-- Only substitue MAX and contracted, and only if the interrupted value is lower
|
|
--
|
|
-- IF iccv.int_val < iccv.cont_val THEN -- quantity check removed in line with interruption comments received on 13/02/2008, AG
|
|
--
|
|
l_return := TRUE;
|
|
--
|
|
-- END IF; -- quantity check removed in line with interruption comments received on 13/02/2008, AG
|
|
--
|
|
END LOOP;
|
|
--
|
|
END LOOP;
|
|
--
|
|
RETURN l_return;
|
|
--
|
|
END am_i_interrrupted;
|
|
--
|
|
--
|
|
--
|
|
PROCEDURE daily_message IS
|
|
--
|
|
l_date DATE;
|
|
l_min_days NUMBER;
|
|
--
|
|
CURSOR cur_inte ( p_inte_id IN interruptions.int_id%TYPE ) IS
|
|
SELECT MIN(incp.max_interruption_days)
|
|
FROM int_conp_coca_vals iccv
|
|
,inty_conp_params incp
|
|
,interruption_types inty
|
|
,contract_categories coca
|
|
WHERE iccv.int_id = p_inte_id
|
|
AND inty.cate_id = coca.cate_id
|
|
AND incp.inty_id = inty.inty_id
|
|
AND iccv.coca_id = coca.coca_id
|
|
AND iccv.conp_id = incp.conp_id
|
|
AND inty.status = 'A';
|
|
--
|
|
BEGIN
|
|
--
|
|
l_date := TRUNC(SYSDATE-cout_system_configuration.get_configuration_item('GAS_DAY_OFFSET')/24);
|
|
--
|
|
FOR int IN ( SELECT inte.int_id
|
|
,l_date - inte.gas_day_start AS days_so_far
|
|
FROM interruptions inte
|
|
WHERE l_date >= inte.gas_day_start
|
|
AND inte.gas_day_end IS NULL
|
|
) LOOP
|
|
--
|
|
OPEN cur_inte (int.int_id);
|
|
FETCH cur_inte
|
|
INTO l_min_days;
|
|
CLOSE cur_inte;
|
|
--
|
|
IF int.days_so_far = l_min_days THEN
|
|
--
|
|
FOR user_rec IN (SELECT DISTINCT syus_id
|
|
FROM user_profiles
|
|
WHERE sypr_id IN (SELECT sypr_id
|
|
FROM system_profiles
|
|
WHERE role_name LIKE 'EFT Admin'
|
|
OR role_name LIKE 'EFT User'
|
|
OR role_name LIKE '%KAM%')) LOOP
|
|
--
|
|
efno_msgsubs.send_messages(p_syus_id => user_rec.syus_id
|
|
,p_suca_id => efno_msgsubs.get_suca_id( p_suca_group => 'Notification'
|
|
, p_suca_name => 'Service' )
|
|
,p_email_content_en => caco_utilities.get_module_text(3849, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
,p_email_subject_en => caco_utilities.get_module_text(3848, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
,p_sms_content_en => caco_utilities.get_module_text(3849, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
ELSIF int.days_so_far >= l_min_days THEN
|
|
--
|
|
FOR user_rec IN (SELECT DISTINCT syus_id
|
|
FROM user_profiles
|
|
WHERE sypr_id IN (SELECT sypr_id
|
|
FROM system_profiles
|
|
WHERE role_name LIKE 'EFT Admin'
|
|
OR role_name LIKE 'EFT User'
|
|
OR role_name LIKE '%KAM%')) LOOP
|
|
--
|
|
efno_msgsubs.send_messages(p_syus_id => user_rec.syus_id
|
|
,p_suca_id => efno_msgsubs.get_suca_id( p_suca_group => 'Notification'
|
|
, p_suca_name => 'Service' )
|
|
,p_email_content_en => caco_utilities.get_module_text(3850, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
,p_email_subject_en => caco_utilities.get_module_text(3848, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
,p_sms_content_en => caco_utilities.get_module_text(3850, caco_utilities.get_syus_lang(user_rec.syus_id))
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP;
|
|
--
|
|
END daily_message;
|
|
--
|
|
--
|
|
--
|
|
PROCEDURE submit_job IS
|
|
--
|
|
i_job binary_integer;
|
|
--
|
|
BEGIN
|
|
--
|
|
dbms_job.submit ( i_job
|
|
, 'efno_interruption.daily_message;'
|
|
, (TRUNC(SYSDATE-cout_system_configuration.get_configuration_item('GAS_DAY_OFFSET')/24) + 10/24)
|
|
, '(TRUNC(SYSDATE-cout_system_configuration.get_configuration_item(''GAS_DAY_OFFSET'')/24) + 10/24)+1'
|
|
);
|
|
--
|
|
END submit_job;
|
|
--
|
|
/**
|
|
-- FUNCTION about
|
|
--
|
|
-- Returns the version number and VSS header for this package
|
|
--
|
|
-- %return The version number and VSS header for this package
|
|
*/
|
|
FUNCTION about RETURN VARCHAR2 IS
|
|
BEGIN
|
|
RETURN(g_revision || CHR(10) || g_header);
|
|
END about;
|
|
--
|
|
--
|
|
BEGIN
|
|
-- Initialization
|
|
NULL;
|
|
--
|
|
END efno_interruption;
|
|
/
|