2158 lines
73 KiB
Plaintext
2158 lines
73 KiB
Plaintext
CREATE OR REPLACE PACKAGE BODY efno_xml_interface /* Copyright Advantica 2008 */ IS
|
|
|
|
---------
|
|
--types--
|
|
---------
|
|
|
|
TYPE r_field IS RECORD (node_name VARCHAR2(500)
|
|
,mandatory_flag BOOLEAN
|
|
);
|
|
|
|
TYPE t_xml_fields IS TABLE OF r_field
|
|
INDEX BY PLS_INTEGER;
|
|
|
|
TYPE t_nom_fields IS TABLE OF r_field
|
|
INDEX BY PLS_INTEGER;
|
|
|
|
TYPE associative_arr is table of NUMBER index by VARCHAR2(500);
|
|
|
|
--------------------
|
|
--global variables--
|
|
--------------------
|
|
|
|
g_xml_fields t_xml_fields;
|
|
g_nom_fields t_nom_fields;
|
|
|
|
g_xml_message xmltype;
|
|
|
|
g_ts_format VARCHAR2(25) := 'dd/mm/yyyy-hh24:mi:ss';
|
|
g_gas_day_format VARCHAR2(10) := 'dd/mm/yyyy';
|
|
|
|
/* g_val owa_util.vc_arr;
|
|
g_gasday owa_util.vc_arr;
|
|
g_coca owa_util.vc_arr;
|
|
g_conp owa_util.vc_arr;
|
|
g_cv owa_util.vc_arr;*/
|
|
g_nnpcv_tab efnow098$.gt_nnpcv_tab;
|
|
g_cont_id NUMBER;
|
|
g_cust_id NUMBER;
|
|
g_error_point VARCHAR2(10) := NULL;
|
|
g_date_format CONSTANT VARCHAR2(20) := nvl(cout_system_configuration.get_configuration_item('g_date_format')
|
|
,'DD/MM/YYYY');
|
|
--------------------
|
|
--global constants--
|
|
--------------------
|
|
|
|
c_valid CONSTANT VARCHAR2(100) := 'valid';
|
|
c_invalid CONSTANT VARCHAR2(100) := 'invalid';
|
|
c_failure CONSTANT VARCHAR2(100) := 'failure';
|
|
c_authorized CONSTANT VARCHAR2(100) := 'authorized';
|
|
c_credential_status CONSTANT VARCHAR2(100) := 'credential_status';
|
|
c_service_request_status CONSTANT VARCHAR2(100) := 'service_request_status';
|
|
c_service_request_status_rsn CONSTANT VARCHAR2(100) := 'service_request_status_reason';
|
|
c_xml_validation_failure_rsn CONSTANT VARCHAR2(100) := 'xml_validation_failure_reason';
|
|
c_nom_creation_failure_rsn CONSTANT VARCHAR2(100) := 'nomination_creation_failure_reason';
|
|
c_error_code CONSTANT VARCHAR2(100) := 'error_code';
|
|
--
|
|
g_spte_single CONSTANT VARCHAR2(100) := 'Single Day';
|
|
--
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
FUNCTION about RETURN VARCHAR2 IS
|
|
--
|
|
--
|
|
BEGIN
|
|
--
|
|
RETURN ( g_revision || CHR(10) || g_header );
|
|
--
|
|
END about;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to convert a boolean value to text
|
|
--
|
|
*/
|
|
|
|
FUNCTION boolean_to_text (p_boolean IN BOOLEAN)
|
|
|
|
RETURN VARCHAR2
|
|
|
|
IS
|
|
|
|
BEGIN
|
|
|
|
IF p_boolean THEN
|
|
RETURN 'true';
|
|
ELSIF NOT p_boolean THEN
|
|
RETURN 'false';
|
|
ELSE
|
|
RETURN 'unknown';
|
|
END IF;
|
|
|
|
END boolean_to_text;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
PROCEDURE display_associative_arr(arr IN associative_arr) IS
|
|
--
|
|
idx VARCHAR2(500);
|
|
--
|
|
BEGIN
|
|
--
|
|
IF arr.COUNT > 0 THEN
|
|
caco_debug.putline('---------------------------------------');
|
|
idx := arr.First;
|
|
while idx is not null loop
|
|
caco_debug.putline(idx||' = '||arr(idx));
|
|
idx := arr.Next(idx);
|
|
END LOOP;
|
|
caco_debug.putline('---------------------------------------');
|
|
END IF;
|
|
--
|
|
END display_associative_arr;
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
PROCEDURE update_associative_arr(arr IN OUT associative_arr
|
|
,name IN VARCHAR2) IS
|
|
--
|
|
idx VARCHAR2(500);
|
|
l_found BOOLEAN := FALSE;
|
|
--
|
|
BEGIN
|
|
--
|
|
IF arr.COUNT > 0 THEN
|
|
idx := arr.First;
|
|
while idx is not null loop
|
|
IF idx = name THEN
|
|
arr(idx) := arr(idx)+1;
|
|
l_found := TRUE;
|
|
EXIT;
|
|
ELSE
|
|
idx := arr.Next(idx);
|
|
END IF;
|
|
END LOOP;
|
|
--
|
|
IF NOT l_found THEN
|
|
arr(name):= 1;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
arr(name):= 1;
|
|
END IF;
|
|
--
|
|
END update_associative_arr;
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to get a specified value from the value array
|
|
@param p_name_array - The array containing all the names of the parameters
|
|
@param p_value_array - The array containing all the values of the parameters
|
|
@param p_name - The name of the parameter we wish to add
|
|
@param p_value - The value of the parameter we wish to add
|
|
--
|
|
*/
|
|
|
|
PROCEDURE add_array_value (p_name_array IN OUT owa.vc_arr
|
|
,p_value_array IN OUT amfr_message_handler.clob_arr
|
|
,p_name IN VARCHAR2
|
|
,p_value IN VARCHAR2
|
|
)
|
|
IS
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_idx NUMBER;
|
|
|
|
BEGIN
|
|
|
|
l_idx := NVL(p_name_array.LAST,0) + 1;
|
|
p_name_array(l_idx) := p_name;
|
|
p_value_array(l_idx) := p_value;
|
|
|
|
END add_array_value;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to get a specified value from the value array
|
|
@param p_name_array - The array containing all the names of the parameters
|
|
@param p_value_array - The array containing all the values of the parameters
|
|
@param p_scan_name - The name of the parameter we wish to find the value of
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_array_value (p_name_array IN owa.vc_arr
|
|
,p_value_array IN amfr_message_handler.clob_arr
|
|
,p_scan_name IN VARCHAR2)
|
|
RETURN VARCHAR2
|
|
|
|
IS
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_return VARCHAR2(4000);
|
|
l_idx NUMBER;
|
|
|
|
BEGIN
|
|
|
|
l_idx := p_name_array.FIRST;
|
|
|
|
FOR i IN 1 .. p_name_array.COUNT LOOP
|
|
|
|
IF lower(p_name_array(l_idx)) = p_scan_name THEN
|
|
l_return := p_value_array(l_idx);
|
|
EXIT;
|
|
END IF;
|
|
|
|
l_idx := p_name_array.NEXT(l_idx);
|
|
|
|
END LOOP;
|
|
|
|
RETURN l_return;
|
|
|
|
END get_array_value;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to populate a failure response in case of general error
|
|
--
|
|
*/
|
|
|
|
PROCEDURE record_error (p_error IN VARCHAR2)
|
|
|
|
IS
|
|
|
|
BEGIN
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status,
|
|
p_value => c_failure);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status_rsn,
|
|
p_value => p_error);
|
|
|
|
END record_error;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to populate a failure response in case of XML validation problems
|
|
--
|
|
*/
|
|
|
|
PROCEDURE raise_xml_validation_error (p_reason IN VARCHAR2)
|
|
|
|
IS
|
|
|
|
BEGIN
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status,
|
|
p_value => c_failure);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status_rsn,
|
|
p_value => 'XML validation failed');
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_xml_validation_failure_rsn,
|
|
p_value => p_reason);
|
|
|
|
END raise_xml_validation_error;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to populate a failure response in case of Nomination creation problems
|
|
--
|
|
*/
|
|
|
|
PROCEDURE raise_nom_creation_error (p_reason IN VARCHAR2)
|
|
|
|
IS
|
|
|
|
BEGIN
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status,
|
|
p_value => c_failure);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status_rsn,
|
|
p_value => 'Nomination creation failed');
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_nom_creation_failure_rsn,
|
|
p_value => p_reason);
|
|
|
|
END raise_nom_creation_error;
|
|
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to validate the log in information passed with the interface request
|
|
--
|
|
*/
|
|
|
|
FUNCTION validate_login
|
|
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_login_success BOOLEAN;
|
|
l_login_message VARCHAR2(2000);
|
|
|
|
BEGIN
|
|
|
|
l_login_success := FALSE;
|
|
|
|
-- Call the security package to process the logon
|
|
caco_security.process_interface_logon(p_username => get_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_scan_name => 'user'),
|
|
p_password => get_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_scan_name => 'password'),
|
|
p_success => l_login_success,
|
|
p_message => l_login_message);
|
|
|
|
IF l_login_success THEN
|
|
|
|
-- Login was successful
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_authorized,
|
|
p_value => boolean_to_text(l_login_success));
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_credential_status,
|
|
p_value => c_valid);
|
|
|
|
RETURN TRUE;
|
|
|
|
ELSE
|
|
|
|
-- Login not successful for some reason
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status,
|
|
p_value => c_failure);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status_rsn,
|
|
p_value => l_login_message);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_credential_status,
|
|
p_value => c_invalid);
|
|
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
-- Exception while checking login
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status,
|
|
p_value => c_failure);
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_service_request_status_rsn,
|
|
p_value => 'Error in checking login information');
|
|
|
|
add_array_value(p_name_array => g_name_array,
|
|
p_value_array => g_value_array,
|
|
p_name => c_credential_status,
|
|
p_value => c_invalid);
|
|
|
|
RETURN FALSE;
|
|
|
|
END validate_login;
|
|
--
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to check that the passed in mandatory nodes exist in the XML
|
|
--
|
|
*/
|
|
|
|
FUNCTION check_mandatory_fields (p_message IN xmltype
|
|
,p_field IN r_field
|
|
,p_failure_msg OUT VARCHAR2
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
BEGIN
|
|
|
|
IF p_field.mandatory_flag
|
|
THEN
|
|
|
|
IF p_message.existsNode(p_field.node_name) = 1
|
|
THEN
|
|
RETURN TRUE;
|
|
ELSE
|
|
p_failure_msg := 'Mandatory field - '||p_field.node_name||' - is missing';
|
|
RETURN FALSE;
|
|
END IF;
|
|
|
|
ELSE
|
|
RETURN TRUE;
|
|
END IF;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
p_failure_msg := 'Error checking mandatory node - '||p_field.node_name||' - '||SQLERRM;
|
|
RETURN FALSE;
|
|
|
|
END check_mandatory_fields;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to get the nominating contract id
|
|
@param p_contract_name - The name of the contract making the nomination
|
|
@param p_gas_day_start - The gas day start of the nomination
|
|
@param p_gas_day_end - The gas day end of the nomination
|
|
@param p_cont_id - The contract_id of the shipper
|
|
--
|
|
*/
|
|
|
|
PROCEDURE get_cont_id (p_contract_name IN contracts.contract_number%TYPE
|
|
,p_gas_day_start IN DATE
|
|
,p_gas_day_end IN DATE
|
|
,p_cont_id OUT contracts.cont_id%TYPE
|
|
,p_cust_id OUT contracts.cust_id%TYPE
|
|
)
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_cont_id IS
|
|
SELECT cont.cont_id,
|
|
cont.cust_id
|
|
FROM contracts cont
|
|
WHERE lower(cont.contract_number) = lower(p_contract_name)
|
|
AND cont.status = 'O'
|
|
AND cont.valid_from <= p_gas_day_start
|
|
AND ( cont.valid_until IS NULL
|
|
OR cont.valid_until >= p_gas_day_end
|
|
) ;
|
|
|
|
BEGIN
|
|
|
|
OPEN c_get_cont_id;
|
|
FETCH c_get_cont_id INTO p_cont_id, p_cust_id;
|
|
CLOSE c_get_cont_id;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
p_cont_id := NULL;
|
|
|
|
END get_cont_id;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
FUNCTION valid_nepo (p_nepo_code IN network_points.code%TYPE
|
|
,p_conp_id OUT cont_network_points.conp_id%TYPE
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_conp IS
|
|
SELECT conp.conp_id
|
|
FROM cont_network_points conp,
|
|
network_points nepo
|
|
WHERE conp.cont_id = g_cont_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND UPPER(nepo.code) = UPPER(p_nepo_code);
|
|
|
|
BEGIN
|
|
|
|
OPEN c_conp;
|
|
FETCH c_conp INTO p_conp_id;
|
|
IF c_conp%NOTFOUND THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3943,amfr_message_handler.g_lang)||': '||p_nepo_code); -- Invalid Network Point
|
|
--
|
|
RETURN FALSE;
|
|
ELSE
|
|
RETURN TRUE;
|
|
END IF;
|
|
CLOSE c_conp;
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
RETURN FALSE;
|
|
|
|
END valid_nepo;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
FUNCTION valid_cate (p_cate_code IN categories.code%TYPE
|
|
,p_gas_day IN DATE
|
|
,p_coca_id OUT contract_categories.coca_id%TYPE
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_coca IS
|
|
SELECT coca.coca_id,
|
|
cate.display_cond
|
|
FROM contract_categories coca,
|
|
categories cate
|
|
WHERE coca.cont_id = g_cont_id
|
|
AND coca.cate_id = cate.cate_id
|
|
AND UPPER(cate.code) = UPPER(p_cate_code);
|
|
--
|
|
l_display_cond categories.display_cond%TYPE;
|
|
--
|
|
BEGIN
|
|
|
|
OPEN c_coca;
|
|
FETCH c_coca INTO p_coca_id, l_display_cond;
|
|
IF c_coca%NOTFOUND THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3944,amfr_message_handler.g_lang)||': '||p_cate_code); -- Invalid Category
|
|
--
|
|
RETURN FALSE;
|
|
ELSIF (l_display_cond = 'LO' AND cout_dates.hours_in_gas_day(p_gas_day) = 25) OR
|
|
l_display_cond = 'SH' AND cout_dates.hours_in_gas_day(p_gas_day) = 23 THEN
|
|
--
|
|
--Nominations interface cannot be used for contracts with long or short day categories
|
|
record_error(caco_utilities.get_module_text(3945,amfr_message_handler.g_lang)||': '||p_cate_code);
|
|
--
|
|
RETURN FALSE;
|
|
ELSE
|
|
RETURN TRUE;
|
|
END IF;
|
|
CLOSE c_coca;
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
RETURN FALSE;
|
|
|
|
END valid_cate;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to validate the XML message
|
|
@param p_sere_id - The service request id of this interface request
|
|
--
|
|
*/
|
|
|
|
FUNCTION validate_xml_message (p_sere_id IN service_reqs.sere_id%TYPE)
|
|
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_xml_message (cp_sere_id service_req_xml.sere_id%TYPE)
|
|
IS
|
|
SELECT srx.xml_data
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = cp_sere_id;
|
|
|
|
CURSOR c_get_child_count (cp_sere_id service_req_xml.sere_id%TYPE
|
|
,cp_child VARCHAR2
|
|
)
|
|
IS
|
|
SELECT COUNT(value(temp_tab))
|
|
FROM service_req_xml srx,
|
|
table(xmlsequence(extract(srx.xml_data, cp_child))) temp_tab
|
|
WHERE srx.sere_id = cp_sere_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_nom_count NUMBER;
|
|
l_field r_field;
|
|
l_failure_msg VARCHAR2(500);
|
|
|
|
BEGIN
|
|
|
|
--Get the xml message
|
|
OPEN c_get_xml_message (p_sere_id);
|
|
FETCH c_get_xml_message INTO g_xml_message;
|
|
CLOSE c_get_xml_message;
|
|
|
|
--Check for all the mandatory nodes that will occur just once
|
|
FOR temp_rec IN g_xml_fields.first .. g_xml_fields.last
|
|
LOOP
|
|
|
|
IF NOT check_mandatory_fields (g_xml_message
|
|
,g_xml_fields(temp_rec)
|
|
,l_failure_msg
|
|
)
|
|
THEN
|
|
caco_debug.putline('validate_xml_message: error 1');
|
|
raise_xml_validation_error (l_failure_msg);
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
END LOOP;
|
|
|
|
--Check the child nodes of the nomination_line node, which can have more than one children
|
|
OPEN c_get_child_count (p_sere_id, g_xml_fields(7).node_name);
|
|
FETCH c_get_child_count INTO l_nom_count;
|
|
CLOSE c_get_child_count;
|
|
|
|
FOR temp_rec IN 1 .. l_nom_count
|
|
LOOP
|
|
|
|
FOR temp_nom_rec IN g_nom_fields.first .. g_nom_fields.last
|
|
LOOP
|
|
|
|
l_field.node_name := g_xml_fields(7).node_name||'['||temp_rec||']/'||g_nom_fields(temp_nom_rec).node_name;
|
|
l_field.mandatory_flag := g_nom_fields(temp_nom_rec).mandatory_flag;
|
|
|
|
IF NOT check_mandatory_fields(g_xml_message
|
|
,l_field
|
|
,l_failure_msg
|
|
)
|
|
THEN
|
|
caco_debug.putline('validate_xml_message: error 2');
|
|
raise_xml_validation_error (l_failure_msg);
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
END LOOP;
|
|
|
|
END LOOP;
|
|
|
|
RETURN TRUE;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
caco_debug.putline('validate_xml_message: error 3');
|
|
raise_xml_validation_error ('Error checking XML values - '||SQLERRM);
|
|
RETURN FALSE;
|
|
|
|
END validate_xml_message;
|
|
--
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to get the time stamp value from the XML
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_ts_node - The char string that identifies the time stamp node
|
|
@param p_ts_value - the out parameter to collect the time stamp value
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_timestamp (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_ts_node IN VARCHAR2
|
|
,p_ts_value OUT DATE
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_ts_str
|
|
IS
|
|
SELECT extractValue(srx.xml_data, p_ts_node)
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = p_sere_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_ts_str VARCHAR2(50);
|
|
|
|
BEGIN
|
|
|
|
OPEN c_get_ts_str;
|
|
FETCH c_get_ts_str INTO l_ts_str;
|
|
CLOSE c_get_ts_str;
|
|
|
|
l_ts_str := rtrim(ltrim(l_ts_str, ' '), ' ');
|
|
p_ts_value := to_date(l_ts_str, g_ts_format);
|
|
RETURN TRUE;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END get_timestamp;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to get the gas day value from the XML
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_gas_day_node - The char string that identifies the gas day node
|
|
@param p_gas_day_value - the out parameter to collect the gas day value
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_gasday (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_gas_day_node IN VARCHAR2
|
|
,p_gas_day_value OUT DATE
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_gasday
|
|
IS
|
|
SELECT extractValue(srx.xml_data, p_gas_day_node)
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = p_sere_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_gas_day_str VARCHAR2(50);
|
|
|
|
BEGIN
|
|
|
|
OPEN c_get_gasday;
|
|
FETCH c_get_gasday INTO l_gas_day_str;
|
|
CLOSE c_get_gasday;
|
|
|
|
l_gas_day_str := rtrim(ltrim(l_gas_day_str, ' '),' ');
|
|
p_gas_day_value := to_date(l_gas_day_str, g_gas_day_format);
|
|
RETURN TRUE;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END get_gasday;
|
|
|
|
---------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to extract the contract name value in the XML nodes
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_cont_node - The char string that identifies the contract name node
|
|
@param p_cont_value - the out parameter to collect the contract name value
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_contract_name (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_cont_node IN VARCHAR2
|
|
,p_cont_value OUT VARCHAR2
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_contract_name
|
|
IS
|
|
SELECT extractValue(srx.xml_data, p_cont_node)
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = p_sere_id;
|
|
|
|
CURSOR c_validate_cont_name (cp_cont_name IN contracts.contract_number%TYPE)
|
|
IS
|
|
SELECT 1
|
|
FROM contracts cont
|
|
WHERE lower(cont.contract_number) = lower(cp_cont_name);
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_cont_name_str VARCHAR2(50);
|
|
l_valid_cont_name NUMBER := 0;
|
|
|
|
BEGIN
|
|
|
|
OPEN c_get_contract_name;
|
|
FETCH c_get_contract_name INTO l_cont_name_str;
|
|
CLOSE c_get_contract_name;
|
|
|
|
l_cont_name_str := rtrim(ltrim(l_cont_name_str, ' '),' ');
|
|
|
|
OPEN c_validate_cont_name (l_cont_name_str);
|
|
FETCH c_validate_cont_name INTO l_valid_cont_name;
|
|
CLOSE c_validate_cont_name;
|
|
|
|
IF l_valid_cont_name = 1
|
|
THEN
|
|
p_cont_value := l_cont_name_str;
|
|
RETURN TRUE;
|
|
ELSE
|
|
RETURN FALSE;
|
|
END IF;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END get_contract_name;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to check that the user has the right to nominate against the contract
|
|
--
|
|
*/
|
|
|
|
FUNCTION valid_user_for_cont RETURN BOOLEAN
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_syus
|
|
IS
|
|
SELECT cust_id
|
|
FROM system_users syus
|
|
WHERE syus.syus_id = caco_security.g_current_syus_id;
|
|
|
|
CURSOR c_inte
|
|
IS
|
|
SELECT '1'
|
|
FROM customer_intermediaries cuin,
|
|
intermediary_users inus,
|
|
intermediaries inte
|
|
WHERE cuin.cust_id = g_cust_id
|
|
AND cuin.inte_id = inus.inte_id
|
|
AND inus.syus_id = caco_security.g_current_syus_id
|
|
AND inte.inte_id = inus.inte_id
|
|
AND inte.period_start < SYSDATE
|
|
AND (inte.period_end > SYSDATE OR inte.period_end IS NULL);
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_cust_id NUMBER;
|
|
l_dummy NUMBER;
|
|
|
|
BEGIN
|
|
|
|
OPEN c_syus;
|
|
FETCH c_syus INTO l_cust_id;
|
|
CLOSE c_syus;
|
|
--
|
|
IF l_cust_id = g_cust_id THEN
|
|
caco_debug.putline('user valid by primary customer');
|
|
RETURN TRUE;
|
|
END IF;
|
|
--
|
|
OPEN c_inte;
|
|
FETCH c_inte INTO l_dummy;
|
|
IF c_inte%FOUND THEN
|
|
caco_debug.putline('user valid by intemediary');
|
|
RETURN TRUE;
|
|
END IF;
|
|
CLOSE c_inte;
|
|
--
|
|
RETURN FALSE;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END valid_user_for_cont;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to check that a single gas day contract is not being used to nominate multiple days
|
|
--
|
|
*/
|
|
|
|
FUNCTION valid_input_format(p_gas_day_start IN DATE
|
|
,p_gas_day_end IN DATE
|
|
) RETURN BOOLEAN
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_spte IS
|
|
SELECT spte.name
|
|
FROM contracts cont
|
|
,spreadsheet_templates spte
|
|
WHERE spte.spte_id = cont.spte_id
|
|
AND spte.spte_type = 'NOST'
|
|
AND cont.cont_id = g_cont_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_spte_name spreadsheet_templates.name%TYPE;
|
|
l_nom_days NUMBER;
|
|
|
|
BEGIN
|
|
|
|
l_nom_days := (to_date(p_gas_day_end,g_date_format) - to_date(p_gas_day_start,g_date_format))+1;
|
|
--
|
|
IF l_nom_days > 1 THEN
|
|
OPEN c_spte;
|
|
FETCH c_spte INTO l_spte_name;
|
|
CLOSE c_spte;
|
|
--
|
|
IF l_spte_name = g_spte_single THEN
|
|
RETURN FALSE;
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN TRUE;
|
|
--
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END valid_input_format;
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to extract the language value in the XML nodes
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_lang_node - The char string that identifies the language node
|
|
@param p_lang_value - the out parameter to collect the language value
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_lang (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_lang_node IN VARCHAR2
|
|
,p_lang_value OUT VARCHAR2
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
/* CURSOR c_get_lang
|
|
IS
|
|
SELECT extractValue(srx.xml_data, p_lang_node)
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = p_sere_id;*/
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_lang_str VARCHAR2(500);
|
|
|
|
BEGIN
|
|
-- SP 16/08/10 commented out cursor. Now we are simply using the system user's lang.
|
|
-- language tag in xml is redundant.
|
|
/* OPEN c_get_lang;
|
|
FETCH c_get_lang INTO l_lang_str;
|
|
CLOSE c_get_lang;*/
|
|
|
|
--l_lang_str := rtrim(ltrim(l_lang_str, ' '),' ');
|
|
l_lang_str := caco_utilities.get_syus_lang;
|
|
|
|
IF l_lang_str IN ('EN','HU') THEN
|
|
--
|
|
p_lang_value := l_lang_str;
|
|
amfr_message_handler.g_lang := l_lang_str;
|
|
--caco_system.set_language(l_lang_str);
|
|
RETURN TRUE;
|
|
--
|
|
ELSE
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END get_lang;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
FUNCTION get_cell_count(p_cont_id IN contracts.cont_id%TYPE,
|
|
p_gas_day_start IN DATE,
|
|
p_gas_day_end IN DATE)
|
|
|
|
RETURN NUMBER
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_conp IS
|
|
SELECT count(*)
|
|
FROM cont_network_points
|
|
WHERE cont_id = p_cont_id;
|
|
|
|
CURSOR c_coca IS
|
|
SELECT count(*)
|
|
FROM contract_categories
|
|
WHERE cont_id = p_cont_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_conp_count NUMBER;
|
|
l_coca_count NUMBER;
|
|
l_nom_days NUMBER;
|
|
|
|
BEGIN
|
|
--
|
|
l_nom_days := (to_date(p_gas_day_end,g_date_format) - to_date(p_gas_day_start,g_date_format))+1;
|
|
--
|
|
OPEN c_conp;
|
|
FETCH c_conp INTO l_conp_count;
|
|
CLOSE c_conp;
|
|
|
|
OPEN c_coca;
|
|
FETCH c_coca INTO l_coca_count;
|
|
CLOSE c_coca;
|
|
|
|
/* caco_debug.putline('l_nom_days: '||l_nom_days);
|
|
caco_debug.putline('l_conp_count: '||l_conp_count);
|
|
caco_debug.putline('l_coca_count: '||l_coca_count);*/
|
|
|
|
RETURN l_conp_count*l_coca_count*l_nom_days;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS THEN
|
|
|
|
RETURN 0;
|
|
|
|
END get_cell_count;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
/*
|
|
--
|
|
Procedure to return the number of nomination lines that should be present per network point
|
|
--
|
|
*/
|
|
FUNCTION get_nepo_line_count(p_cont_id IN contracts.cont_id%TYPE,
|
|
p_gas_day_start IN DATE,
|
|
p_gas_day_end IN DATE)
|
|
|
|
RETURN NUMBER
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_coca IS
|
|
SELECT count(*)
|
|
FROM contract_categories
|
|
WHERE cont_id = p_cont_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_coca_count NUMBER;
|
|
l_nom_days NUMBER;
|
|
|
|
BEGIN
|
|
--
|
|
l_nom_days := (to_date(p_gas_day_end,g_date_format) - to_date(p_gas_day_start,g_date_format))+1;
|
|
--
|
|
OPEN c_coca;
|
|
FETCH c_coca INTO l_coca_count;
|
|
CLOSE c_coca;
|
|
|
|
RETURN l_coca_count*l_nom_days;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS THEN
|
|
|
|
RETURN 0;
|
|
|
|
END get_nepo_line_count;
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
/*
|
|
--
|
|
Procedure to return the number of nomination lines that should be present per network point
|
|
--
|
|
*/
|
|
FUNCTION get_cate_line_count(p_cont_id IN contracts.cont_id%TYPE,
|
|
p_gas_day_start IN DATE,
|
|
p_gas_day_end IN DATE)
|
|
|
|
RETURN NUMBER
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_conp IS
|
|
SELECT count(*)
|
|
FROM cont_network_points
|
|
WHERE cont_id = p_cont_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_conp_count NUMBER;
|
|
l_nom_days NUMBER;
|
|
|
|
BEGIN
|
|
--
|
|
l_nom_days := (to_date(p_gas_day_end,g_date_format) - to_date(p_gas_day_start,g_date_format))+1;
|
|
--
|
|
OPEN c_conp;
|
|
FETCH c_conp INTO l_conp_count;
|
|
CLOSE c_conp;
|
|
|
|
RETURN l_conp_count*l_nom_days;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS THEN
|
|
|
|
RETURN 0;
|
|
|
|
END get_cate_line_count;
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to extract the nomination values in the XML nodes
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_nom_dets_node - The char string that identifies the nomination node
|
|
--
|
|
*/
|
|
|
|
FUNCTION get_nom_dets (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_nom_dets_node IN VARCHAR2
|
|
,p_gas_day_start IN DATE
|
|
,p_gas_day_end IN DATE
|
|
)
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
|
|
-----------
|
|
--cursors--
|
|
-----------
|
|
|
|
CURSOR c_get_child_count (cp_sere_id service_req_xml.sere_id%TYPE
|
|
,cp_child VARCHAR2
|
|
)
|
|
IS
|
|
SELECT COUNT(value(temp_tab))
|
|
FROM service_req_xml srx,
|
|
table(xmlsequence(extract(srx.xml_data, cp_child))) temp_tab
|
|
WHERE srx.sere_id = cp_sere_id;
|
|
|
|
CURSOR c_get_nom_dets (cp_node IN VARCHAR2)
|
|
IS
|
|
SELECT extractValue(srx.xml_data, cp_node)
|
|
FROM service_req_xml srx
|
|
WHERE srx.sere_id = p_sere_id;
|
|
|
|
-------------
|
|
--variables--
|
|
-------------
|
|
|
|
l_nom_count NUMBER := 0;
|
|
l_gas_day_str VARCHAR2(500);
|
|
l_gas_day DATE;
|
|
l_network_point_code VARCHAR2(500);
|
|
l_category_code VARCHAR2(500);
|
|
l_value_str VARCHAR2(500);
|
|
l_value NUMBER;
|
|
l_success BOOLEAN := TRUE;
|
|
l_conp_id NUMBER;
|
|
l_coca_id NUMBER;
|
|
--
|
|
l_nepo associative_arr;
|
|
l_cate associative_arr;
|
|
--
|
|
l_nepo_idx VARCHAR2(500);
|
|
l_cate_idx VARCHAR2(500);
|
|
--
|
|
BEGIN
|
|
|
|
OPEN c_get_child_count (p_sere_id, p_nom_dets_node);
|
|
FETCH c_get_child_count INTO l_nom_count;
|
|
CLOSE c_get_child_count;
|
|
--
|
|
caco_debug.putline('l_nom_count:'|| l_nom_count);
|
|
FOR temp_rec IN 1 .. l_nom_count LOOP
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 1');
|
|
OPEN c_get_nom_dets (p_nom_dets_node||'['||temp_rec||']/'||g_nom_fields(1).node_name);
|
|
FETCH c_get_nom_dets INTO l_gas_day_str;
|
|
CLOSE c_get_nom_dets;
|
|
--
|
|
IF l_gas_day_str IS NULL THEN
|
|
raise_xml_validation_error(g_nom_fields(1).node_name||' IS NULL');
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 2');
|
|
l_gas_day_str := rtrim(ltrim(l_gas_day_str, ' '),' ');
|
|
l_gas_day := to_date(l_gas_day_str, g_gas_day_format); -- this will throw exception if invalid date
|
|
--
|
|
-- check gas day value against header record values
|
|
--
|
|
IF l_gas_day NOT BETWEEN p_gas_day_start AND p_gas_day_end THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3946,amfr_message_handler.g_lang)||': '||l_gas_day_str); -- Invalid Gas Day
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--caco_debug.putline('get_nom_dets: message 3');
|
|
OPEN c_get_nom_dets (p_nom_dets_node||'['||temp_rec||']/'||g_nom_fields(2).node_name);
|
|
FETCH c_get_nom_dets INTO l_network_point_code;
|
|
CLOSE c_get_nom_dets;
|
|
--
|
|
IF l_network_point_code IS NULL THEN
|
|
raise_xml_validation_error(g_nom_fields(2).node_name||' IS NULL');
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 4');
|
|
l_network_point_code := rtrim(ltrim(l_network_point_code, ' '),' ');
|
|
--
|
|
-- need to validate network point code against network_points and contract_network_points
|
|
--
|
|
IF NOT valid_nepo(l_network_point_code,l_conp_id) THEN
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
update_associative_arr(l_nepo,l_network_point_code);
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 5');
|
|
OPEN c_get_nom_dets (p_nom_dets_node||'['||temp_rec||']/'||g_nom_fields(3).node_name);
|
|
FETCH c_get_nom_dets INTO l_category_code;
|
|
CLOSE c_get_nom_dets;
|
|
--
|
|
IF l_category_code IS NULL THEN
|
|
raise_xml_validation_error(g_nom_fields(3).node_name||' IS NULL');
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 6');
|
|
l_category_code := rtrim(ltrim(l_category_code, ' '),' ');
|
|
--
|
|
-- need to validate category code against categories and contract_categories
|
|
--
|
|
IF NOT valid_cate(l_category_code,l_gas_day,l_coca_id) THEN
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
update_associative_arr(l_cate,l_category_code);
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 7');
|
|
OPEN c_get_nom_dets (p_nom_dets_node||'['||temp_rec||']/'||g_nom_fields(4).node_name);
|
|
FETCH c_get_nom_dets INTO l_value_str;
|
|
CLOSE c_get_nom_dets;
|
|
--
|
|
IF l_value_str IS NULL THEN
|
|
raise_xml_validation_error(g_nom_fields(4).node_name||' IS NULL');
|
|
l_success := FALSE;
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('get_nom_dets: message 8');
|
|
l_value_str := rtrim(ltrim(l_value_str, ' '),' ');
|
|
l_value := to_number(l_value_str); -- this will throw exception if invalid number
|
|
--caco_debug.putline('get_nom_dets: message 9');
|
|
--
|
|
-- Lets build up the table of records global variable
|
|
--
|
|
g_nnpcv_tab(temp_rec).gas_day := l_gas_day;
|
|
g_nnpcv_tab(temp_rec).conp_id := l_conp_id;
|
|
g_nnpcv_tab(temp_rec).coca_id := l_coca_id;
|
|
g_nnpcv_tab(temp_rec).value := l_value;
|
|
--
|
|
END LOOP;
|
|
--
|
|
-- check the number of nomination lines
|
|
--
|
|
IF get_cell_count(g_cont_id,p_gas_day_start,p_gas_day_end) <> g_nnpcv_tab.COUNT THEN
|
|
--File contains the wrong number of nomination lines for this contract and gas day range: x expected, y found
|
|
record_error(caco_utilities.get_module_text(3947,amfr_message_handler.g_lang)||': '||
|
|
get_cell_count(g_cont_id,p_gas_day_start,p_gas_day_end)||' '||
|
|
caco_utilities.get_module_text(3948,amfr_message_handler.g_lang)||', '||
|
|
g_nnpcv_tab.COUNT||' '||caco_utilities.get_module_text(3949,amfr_message_handler.g_lang)||'.');
|
|
l_success := FALSE;
|
|
END IF;
|
|
--
|
|
-- check the nepo array to make sure there are not too many of one network point
|
|
--
|
|
IF l_success THEN
|
|
IF l_nepo.COUNT > 0 THEN
|
|
l_nepo_idx := l_nepo.First;
|
|
while l_nepo_idx is not null loop
|
|
IF l_nepo(l_nepo_idx) > get_nepo_line_count(g_cont_id,p_gas_day_start,p_gas_day_end) THEN
|
|
-- File contains too many nomination lines containing network point: <nepo_name>
|
|
record_error(caco_utilities.get_module_text(3957,amfr_message_handler.g_lang)||': '||l_nepo_idx);
|
|
l_success := FALSE;
|
|
EXIT;
|
|
ELSE
|
|
l_nepo_idx := l_nepo.Next(l_nepo_idx);
|
|
END IF;
|
|
END LOOP;
|
|
--
|
|
ELSE
|
|
-- no network points found - should never happen!
|
|
l_success := FALSE;
|
|
record_error('No Network Points found');
|
|
END IF;
|
|
END IF;
|
|
--
|
|
-- check the cate array to make sure there are not too many of one category
|
|
--
|
|
IF l_success THEN
|
|
IF l_cate.COUNT > 0 THEN
|
|
l_cate_idx := l_cate.First;
|
|
while l_cate_idx is not null loop
|
|
IF l_cate(l_cate_idx) > get_cate_line_count(g_cont_id,p_gas_day_start,p_gas_day_end) THEN
|
|
-- File contains too many nomination lines containing category: <cate_name>
|
|
record_error(caco_utilities.get_module_text(3958,amfr_message_handler.g_lang)||': '||l_cate_idx);
|
|
l_success := FALSE;
|
|
EXIT;
|
|
ELSE
|
|
l_cate_idx := l_cate.Next(l_cate_idx);
|
|
END IF;
|
|
END LOOP;
|
|
--
|
|
ELSE
|
|
-- no categories found - should never happen!
|
|
l_success := FALSE;
|
|
record_error('No Categories found');
|
|
END IF;
|
|
END IF;
|
|
--
|
|
-- Output the various arrays for debug purposes
|
|
efnow098$.display_nnpcv_tab(g_nnpcv_tab);
|
|
display_associative_arr(l_nepo);
|
|
display_associative_arr(l_cate);
|
|
--
|
|
IF l_success THEN
|
|
RETURN TRUE;
|
|
ELSE
|
|
RETURN FALSE;
|
|
END IF;
|
|
--
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
RETURN FALSE;
|
|
|
|
END get_nom_dets;
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to extract the values in the XML nodes
|
|
@param p_sere_id - The service request id of this interface request
|
|
@param p_timestamp - the timestamp when this interface request was sent
|
|
@param p_gas_day - the gas day for which we are creating allocations
|
|
@param p_shipper - the shipper creating the nomination
|
|
@param p_cont_type - the contract type against which the nominating shipper is creating the nomination
|
|
@param p_store - the store against which a store specific shipper is creating the nomination
|
|
@param p_ship_pair_code_i - the shipperpair for injection
|
|
@param p_ship_pair_code_w - the shipperpair for withdrawal
|
|
@param p_ship_pair_quantity_i - the corresponding quantity for the shipper pair for injection
|
|
@param p_ship_pair_quantity_w - the corresponding quantity for the shipper pair for withdrawal
|
|
--
|
|
*/
|
|
|
|
FUNCTION extract_values (p_sere_id IN service_req_xml.sere_id%TYPE
|
|
,p_contract_name OUT VARCHAR2
|
|
,p_timestamp OUT DATE
|
|
,p_gas_day_start OUT DATE
|
|
,p_gas_day_end OUT DATE
|
|
,p_language OUT VARCHAR2
|
|
)
|
|
|
|
RETURN BOOLEAN
|
|
|
|
IS
|
|
--
|
|
l_username system_users.db_username%TYPE;
|
|
--
|
|
BEGIN
|
|
|
|
IF NOT get_contract_name(p_sere_id, g_xml_fields(1).node_name, p_contract_name)
|
|
THEN
|
|
|
|
raise_xml_validation_error (g_xml_fields(1).node_name||' '||caco_utilities.get_module_text(3950,amfr_message_handler.g_lang)); -- value is invalid
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
IF NOT get_timestamp(p_sere_id, g_xml_fields(2).node_name, p_timestamp)
|
|
THEN
|
|
|
|
raise_xml_validation_error (g_xml_fields(2).node_name||' '||caco_utilities.get_module_text(3950,amfr_message_handler.g_lang)); -- value is invalid
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
IF NOT get_gasday(p_sere_id, g_xml_fields(3).node_name, p_gas_day_start)
|
|
THEN
|
|
|
|
raise_xml_validation_error (g_xml_fields(3).node_name||' '||caco_utilities.get_module_text(3950,amfr_message_handler.g_lang)); -- value is invalid
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
|
|
IF NOT get_gasday(p_sere_id, g_xml_fields(4).node_name, p_gas_day_end)
|
|
THEN
|
|
|
|
raise_xml_validation_error (g_xml_fields(4).node_name||' '||caco_utilities.get_module_text(3950,amfr_message_handler.g_lang)); -- value is invalid
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
-- validate the dates
|
|
IF p_gas_day_end < p_gas_day_start THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3951,amfr_message_handler.g_lang)); -- Gas Day End is before Gas Day Start
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF p_gas_day_start < trunc(sysdate) THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3952,amfr_message_handler.g_lang)); -- Gas Day Start must be in the future
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF NOT get_lang(p_sere_id, g_xml_fields(5).node_name, p_language) THEN
|
|
--
|
|
raise_xml_validation_error (g_xml_fields(5).node_name||' value is invalid');
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
-- Get the contract id
|
|
--
|
|
get_cont_id (p_contract_name
|
|
,p_gas_day_start
|
|
,p_gas_day_end
|
|
,g_cont_id
|
|
,g_cust_id
|
|
);
|
|
|
|
IF g_cont_id IS NULL
|
|
THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3939,amfr_message_handler.g_lang)); --Invalid Contract
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF NOT valid_input_format(p_gas_day_start, p_gas_day_end) THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3956,amfr_message_handler.g_lang)); --Cannot nominate multiple gas days for a single gas day contract
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
caco_debug.putline('caco_security.g_current_syus_id: '||caco_security.g_current_syus_id);
|
|
--
|
|
IF NOT valid_user_for_cont THEN
|
|
--
|
|
record_error(caco_utilities.get_module_text(3955,amfr_message_handler.g_lang)); --Invalid User for Contract
|
|
--
|
|
RETURN FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF NOT get_nom_dets(p_sere_id, g_xml_fields(7).node_name, p_gas_day_start, p_gas_day_end)
|
|
THEN
|
|
|
|
raise_xml_validation_error (g_xml_fields(7).node_name||' value is invalid');
|
|
RETURN FALSE;
|
|
|
|
END IF;
|
|
--
|
|
RETURN TRUE;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
raise_xml_validation_error ('Error in extracting and validating XML values - '||SQLERRM);
|
|
RETURN FALSE;
|
|
|
|
END extract_values;
|
|
|
|
--------------------------------------------------------------------------------------------------------------------------------------------
|
|
--------------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
PROCEDURE submit_nomination ( p_timestamp IN DATE
|
|
, p_gasday_start IN DATE
|
|
, p_gasday_end IN DATE
|
|
) IS
|
|
--
|
|
-- Parameters are short intentionally
|
|
--
|
|
l_message VARCHAR2(1000);
|
|
l_mess_type VARCHAR2(1000);
|
|
l_sub_list caco_utilities.g_t_substitution_list;
|
|
--
|
|
e_ude EXCEPTION;
|
|
l_date DATE;
|
|
--
|
|
l_nomi_id nominations.nomi_id%TYPE;
|
|
--
|
|
l_nomi_details VARCHAR2(4000);
|
|
l_timestamp DATE;
|
|
l_letter VARCHAR2(4000);
|
|
--
|
|
l_c_nnpcv_tab efno_confirmations.nnpcv_tab;
|
|
l_rule_results BOOLEAN := TRUE;
|
|
--
|
|
l_cnp_count NUMBER;
|
|
--
|
|
l_idx NUMBER := NULL;
|
|
--
|
|
l_rcve_b4_start NUMBER := 0; -- Contract receive before start
|
|
--
|
|
l_num_format VARCHAR2(50);
|
|
--
|
|
l_tot_perc_split NUMBER := 0;
|
|
--
|
|
-- dbms_lock values
|
|
--
|
|
l_noms_lock NUMBER;
|
|
l_noms_release NUMBER;
|
|
--
|
|
--l_nom_days NUMBER := 0;
|
|
--
|
|
l_loop_counter NUMBER := 1;
|
|
l_coca_id NUMBER;
|
|
--
|
|
CURSOR cu_coca(c_disp_cond IN categories.display_cond%TYPE) IS
|
|
SELECT coca.coca_id
|
|
FROM contract_categories coca
|
|
,categories cate
|
|
WHERE cate.cate_id = coca.cate_id
|
|
AND coca.cont_id = g_cont_id
|
|
AND cate.display_cond = c_disp_cond;
|
|
--
|
|
BEGIN
|
|
--
|
|
-- Attempt to lock nominations table
|
|
--
|
|
caco_debug.putline('Entered default_values');
|
|
--
|
|
l_noms_lock := dbms_lock.request(id => 128
|
|
,lockmode => 6
|
|
,timeout => 180);
|
|
caco_debug.putline('default_values DBMS_LOCK id 128 request value l_noms_lock is ' ||
|
|
l_noms_lock);
|
|
--
|
|
IF l_noms_lock = 0 THEN
|
|
BEGIN
|
|
--
|
|
-- Set the initial error point
|
|
--
|
|
g_error_point := 'A005';
|
|
--
|
|
--l_nom_days := (to_date(p_gasday_end,g_date_format) - to_date(p_gasday_start,g_date_format))+1;
|
|
--
|
|
-- Anonymous block to handle exceptions
|
|
--
|
|
-- Verify the nomination
|
|
--
|
|
-- Get the "Receive Before Start" parameter for the contract
|
|
l_rcve_b4_start := efnow098$.get_receive_before_start(g_cont_id);
|
|
--
|
|
g_error_point := 'A167';
|
|
--
|
|
caco_debug.putline('SP-------------g_cont_id: '||g_cont_id);
|
|
--
|
|
SELECT COUNT(*)
|
|
INTO l_cnp_count
|
|
FROM cont_network_points conp
|
|
,network_points nepo
|
|
WHERE conp.cont_id = g_cont_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND ((nepo.nepo_type = 'V' AND efno_contracts.emo_contract(g_cont_id) = 'Y') OR
|
|
(nepo.nepo_type IN ('N','X') AND efno_contracts.emo_contract(g_cont_id) = 'N'));
|
|
--
|
|
l_date := p_gasday_start;
|
|
--
|
|
g_error_point := 'A168';
|
|
--
|
|
LOOP
|
|
--
|
|
-- Check the gate closure
|
|
--
|
|
IF NOT efnow098$.check_gate_closure ( p_cont_id => g_cont_id
|
|
, p_date => l_date
|
|
, p_message => l_message
|
|
) THEN
|
|
--
|
|
record_error(l_message);
|
|
--
|
|
RAISE e_ude;
|
|
--
|
|
END IF;
|
|
--
|
|
-- Check the date against the "Receive Before Start" parameter
|
|
--
|
|
IF ( l_date - TRUNC(SYSDATE) ) > l_rcve_b4_start THEN
|
|
--
|
|
-- it is too early to nominate for this gas day.
|
|
caco_utilities.get_exception_message(p_exception_number => -20527
|
|
,p_message => l_message
|
|
,p_exme_type => l_mess_type
|
|
,p_substitution_list => l_sub_list
|
|
,p_language => amfr_message_handler.g_lang
|
|
);
|
|
record_error(l_message);
|
|
--
|
|
RAISE e_ude;
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
g_error_point := 'A169';
|
|
--
|
|
IF l_date < p_gasday_end THEN
|
|
l_date := l_date + 1;
|
|
ELSE
|
|
EXIT;
|
|
END IF;
|
|
--
|
|
END LOOP;
|
|
--
|
|
-- Dates look OK, move on to numbers
|
|
--
|
|
g_error_point := 'A170';
|
|
--
|
|
FOR i IN 1..g_nnpcv_tab.COUNT LOOP
|
|
--
|
|
IF INSTR(TO_CHAR(g_nnpcv_tab(i).value),'.') > 0 THEN
|
|
--
|
|
-- Number entered has a decimal, lets check it's within range, lookup format
|
|
--
|
|
g_error_point := 'A242';
|
|
--
|
|
l_num_format := NULL;
|
|
--
|
|
SELECT c.number_format
|
|
INTO l_num_format
|
|
FROM categories c
|
|
,contract_categories cc
|
|
WHERE c.cate_id = cc.cate_id
|
|
AND cc.coca_id = g_nnpcv_tab(i).coca_id;
|
|
--
|
|
-- Now compare the number formats
|
|
--
|
|
IF (LENGTH(TO_CHAR(g_nnpcv_tab(i).value)) - INSTR(TO_CHAR(g_nnpcv_tab(i).value),'.')) > (LENGTH(l_num_format) - INSTR(l_num_format||'.','.')) THEN
|
|
--
|
|
-- Number of decimals in supplied format greater than number of decimals in format mask
|
|
--
|
|
g_error_point := 'A243';
|
|
--
|
|
l_message := caco_utilities.get_module_text(p_text_number => 2240 );
|
|
--
|
|
record_error(l_message);
|
|
--
|
|
RAISE e_ude;
|
|
--
|
|
END IF;
|
|
--
|
|
END IF;
|
|
END LOOP;
|
|
--
|
|
g_error_point := 'A175';
|
|
--
|
|
-- Because rules are based on data in the nominations table, we need to insert it here...
|
|
--
|
|
DBMS_TRANSACTION.SAVEPOINT(g_cont_id);
|
|
--
|
|
-- Insert the nomination header
|
|
--
|
|
INSERT INTO nominations ( status
|
|
, identifier
|
|
, cont_id
|
|
)
|
|
VALUES ( 'A'
|
|
, 1
|
|
, g_cont_id
|
|
)
|
|
RETURNING nomi_id INTO l_nomi_id;
|
|
--
|
|
UPDATE nominations
|
|
SET identifier = l_nomi_id
|
|
WHERE nomi_id = l_nomi_id;
|
|
--
|
|
g_error_point := 'A280';
|
|
--
|
|
l_nomi_details := 'NOM:'||l_nomi_id||' ID:'||l_nomi_id||' CONT:'||g_cont_id||'DETAILS:';
|
|
--
|
|
-- check if it is an entry mandatory offer contract
|
|
-- no requirement in interface spec for it having to cope with EMO contracts!
|
|
IF efno_contracts.emo_contract(g_cont_id) = 'Y' THEN
|
|
/* --
|
|
OPEN c_tot_perc_split(g_cont_id);
|
|
FETCH c_tot_perc_split INTO l_tot_perc_split;
|
|
CLOSE c_tot_perc_split;
|
|
--
|
|
IF l_tot_perc_split = 0 THEN
|
|
IF caco_utilities.user_has_EFT_admin = 'Y' THEN
|
|
-- Percentage split contract parameters have not been set up correctly
|
|
l_message := caco_utilities.get_module_text(3917);
|
|
ELSE
|
|
-- A more customer friendly error message..
|
|
-- An error has occurred in validating this nomination. Please contact support.
|
|
l_message := caco_utilities.get_module_text(3923);
|
|
END IF;
|
|
g_error_point := 'A282';
|
|
RAISE e_ude;
|
|
END IF;
|
|
--
|
|
FOR nnpcv_idx IN g_nnpcv_tab.FIRST..g_nnpcv_tab.LAST LOOP
|
|
--
|
|
-- check that it is a virtual network point
|
|
IF efno_contracts.virtual_nepo(g_nnpcv_tab(nnpcv_idx).conp_id) THEN
|
|
-- insert a record for each non virtual network point assigned to the contract
|
|
-- using the virtual nepo nominated values and percentage split parameter
|
|
FOR i IN c_conp(g_cont_id) LOOP
|
|
--
|
|
INSERT INTO nom_net_point_cat_vals ( value
|
|
, gas_day
|
|
, coca_id
|
|
, nomi_id
|
|
, conp_id
|
|
)
|
|
VALUES ( ROUND((i.perc_split/l_tot_perc_split)*g_nnpcv_tab(nnpcv_idx).value)
|
|
, g_nnpcv_tab(nnpcv_idx).gas_day
|
|
, g_nnpcv_tab(nnpcv_idx).coca_id
|
|
, l_nomi_id
|
|
, i.conp_id
|
|
);
|
|
END LOOP;
|
|
ELSE
|
|
-- Nominations for Entry Manadatory Offer Contracts must be against a virtual network point
|
|
l_message := caco_utilities.get_module_text(3916);
|
|
--
|
|
RAISE e_ude;
|
|
END IF;
|
|
--
|
|
END LOOP;*/
|
|
--
|
|
--Nominations interface cannot be used for Entry Manadatory Offer Contracts
|
|
record_error(caco_utilities.get_module_text(3953,amfr_message_handler.g_lang));
|
|
--
|
|
RAISE e_ude;
|
|
END IF;
|
|
--
|
|
FOR nnpcv_idx IN g_nnpcv_tab.FIRST..g_nnpcv_tab.LAST LOOP
|
|
--
|
|
-- Would only use forall if it wasn't for pls-00436...
|
|
--
|
|
INSERT INTO nom_net_point_cat_vals ( value
|
|
, gas_day
|
|
, coca_id
|
|
, nomi_id
|
|
, conp_id
|
|
)
|
|
VALUES ( g_nnpcv_tab(nnpcv_idx).value
|
|
, g_nnpcv_tab(nnpcv_idx).gas_day
|
|
, g_nnpcv_tab(nnpcv_idx).coca_id
|
|
, l_nomi_id
|
|
, g_nnpcv_tab(nnpcv_idx).conp_id
|
|
);
|
|
--
|
|
l_nomi_details := SUBSTR(l_nomi_details||' Day:'||g_nnpcv_tab(nnpcv_idx).gas_day||' Cat:'||g_nnpcv_tab(nnpcv_idx).coca_id||' Net:'||g_nnpcv_tab(nnpcv_idx).conp_id||' Val:'||g_nnpcv_tab(nnpcv_idx).value
|
|
,1
|
|
,4000
|
|
);
|
|
--
|
|
END LOOP;
|
|
--
|
|
-- Now enact the rules
|
|
--
|
|
l_rule_results := efno_nominations.rule_loops( l_nomi_id
|
|
, g_cont_id
|
|
, l_message
|
|
, l_c_nnpcv_tab
|
|
);
|
|
--
|
|
-- Check the status of the rules
|
|
--
|
|
IF l_rule_results THEN
|
|
--
|
|
-- questionable results
|
|
--
|
|
IF l_message IS NULL THEN
|
|
--
|
|
l_message := caco_utilities.get_module_text(2270,amfr_message_handler.g_lang);
|
|
--
|
|
END IF;
|
|
--
|
|
record_error(caco_utilities.get_module_text(3954,amfr_message_handler.g_lang)||': '||l_message);
|
|
--
|
|
RAISE e_ude;
|
|
--
|
|
END IF;
|
|
--
|
|
g_error_point := 'A370';
|
|
--
|
|
-- Update existing nominations to inactive
|
|
--
|
|
l_idx := g_nnpcv_tab.COUNT; -- not sure why we can't imbed this in the SQL below, but we can't
|
|
--
|
|
UPDATE nominations nomi
|
|
SET nomi.status = 'I'
|
|
WHERE nomi.cont_id = g_cont_id
|
|
AND nomi.nomi_id <> l_nomi_id
|
|
AND EXISTS ( SELECT NULL
|
|
FROM nom_net_point_cat_vals nnpcv
|
|
WHERE nnpcv.nomi_id = nomi.nomi_id
|
|
AND nnpcv.gas_day BETWEEN g_nnpcv_tab(1).gas_day AND g_nnpcv_tab(l_idx).gas_day
|
|
)
|
|
AND NOT EXISTS ( SELECT NULL
|
|
FROM nom_net_point_cat_vals nnpcv
|
|
WHERE nnpcv.nomi_id = nomi.nomi_id
|
|
AND nnpcv.gas_day NOT BETWEEN g_nnpcv_tab(1).gas_day AND g_nnpcv_tab(l_idx).gas_day
|
|
);
|
|
--
|
|
g_error_point := 'A371';
|
|
--
|
|
-- Timestamp
|
|
--
|
|
/* l_timestamp := efnow098$.timestamp_nomi ( p_nomi_id => l_nomi_id
|
|
, p_nomi_details => l_nomi_details
|
|
);*/
|
|
--
|
|
g_error_point := 'A372';
|
|
--
|
|
-- Notification
|
|
--
|
|
l_letter := efnow098$.send_nom_notification ( p_cont_id => g_cont_id
|
|
, p_cust_id => g_cust_id
|
|
, p_nomi_identifier => l_nomi_id
|
|
, p_gas_day_start => g_nnpcv_tab(1).gas_day
|
|
, p_gas_day_end => g_nnpcv_tab(g_nnpcv_tab.COUNT).gas_day
|
|
, p_timestamp => p_timestamp
|
|
);
|
|
--
|
|
g_error_point := 'A373';
|
|
--
|
|
-- Create confimation
|
|
--
|
|
INSERT INTO confirmations ( confirmation_type
|
|
, confirmation_sent
|
|
, confirmation
|
|
, nomi_id
|
|
, confirmation_text
|
|
, approved
|
|
)
|
|
VALUES ( 'NO'
|
|
, p_timestamp
|
|
, NULL -- will add later
|
|
, l_nomi_id
|
|
, l_letter
|
|
, 'Y'
|
|
);
|
|
--
|
|
g_error_point := 'A374';
|
|
--
|
|
-- Save Spreadsheet
|
|
--
|
|
IF NVL(cout_system_configuration.get_configuration_item('G_SAVE_NOM_TEMPLATE'),'Y') = 'Y' THEN
|
|
--
|
|
amfr_excel.get_template(p_id => g_cont_id
|
|
,p_type => amfr_excel.gc_nomination
|
|
,p_nomi_conf_id => l_nomi_id
|
|
,p_mode => 'INSERT'
|
|
);
|
|
--
|
|
END IF;
|
|
--
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
--
|
|
-- Rollback the transaction just in case...
|
|
--
|
|
BEGIN
|
|
DBMS_TRANSACTION.ROLLBACK_SAVEPOINT(g_cont_id);
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
NULL;
|
|
END;
|
|
--
|
|
caco_debug.putline('error - '||g_error_point||' - '||sqlcode||' - '||SQLERRM);
|
|
--
|
|
cout_err.report_and_go(p_exception_number => sqlcode
|
|
,p_exception_message => g_error_point||' : '||sqlerrm
|
|
);
|
|
--
|
|
END;
|
|
--
|
|
-- release lock on nominations table
|
|
--
|
|
l_noms_release := dbms_lock.release(id => 128);
|
|
caco_debug.putline('default_values DBMS_LOCK id 128 release value l_noms_release is ' ||
|
|
l_noms_release);
|
|
END IF;
|
|
--
|
|
--
|
|
END submit_nomination;
|
|
|
|
--------------------------------------------------------------------------------------------------------------------------------------------
|
|
--------------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
/*
|
|
--
|
|
Procedure to start processing the XML message
|
|
--
|
|
*/
|
|
|
|
PROCEDURE process_xml_message IS
|
|
--
|
|
-- variables
|
|
--
|
|
l_contract_name VARCHAR2(200);
|
|
l_timestamp DATE;
|
|
l_gas_day_start DATE;
|
|
l_gas_day_end DATE;
|
|
l_language VARCHAR2(2);
|
|
--
|
|
BEGIN
|
|
--
|
|
caco_debug.putline('---------start of process_xml_message----------');
|
|
--
|
|
-- Validate the login details
|
|
--
|
|
IF validate_login THEN
|
|
--
|
|
-- Validate the XML message
|
|
-- This will check only the occurence of required nodes and not their permissible values
|
|
--
|
|
IF validate_xml_message (g_sere_id) THEN
|
|
--
|
|
-- This will extract the values from the nodes and check against permissible values
|
|
-- If all values are correct, then it will fill those in the respective variables
|
|
--
|
|
IF extract_values (g_sere_id
|
|
,l_contract_name
|
|
,l_timestamp
|
|
,l_gas_day_start
|
|
,l_gas_day_end
|
|
,l_language
|
|
)
|
|
THEN
|
|
--
|
|
-- Perform more validation and insert the nomination
|
|
--
|
|
submit_nomination(p_timestamp => SYSDATE -- l_timestamp /* removed as customer could supply anything, and replaced with current date/time*/
|
|
,p_gasday_start => l_gas_day_start
|
|
,p_gasday_end => l_gas_day_end);
|
|
--
|
|
END IF;
|
|
|
|
END IF;
|
|
|
|
END IF;
|
|
|
|
EXCEPTION
|
|
|
|
WHEN OTHERS
|
|
THEN
|
|
|
|
raise_nom_creation_error('Error while creating nominations - '||SQLERRM);
|
|
|
|
END process_xml_message;
|
|
|
|
/*
|
|
--
|
|
Procedure to start processing the XML message
|
|
--
|
|
*/
|
|
|
|
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------------------------------------------------------------
|
|
|
|
BEGIN
|
|
|
|
g_xml_fields(1).node_name := 'nomination/contract';
|
|
g_xml_fields(1).mandatory_flag := TRUE;
|
|
g_xml_fields(2).node_name := 'nomination/timestamp';
|
|
g_xml_fields(2).mandatory_flag := TRUE;
|
|
g_xml_fields(3).node_name := 'nomination/gas_day_start';
|
|
g_xml_fields(3).mandatory_flag := TRUE;
|
|
g_xml_fields(4).node_name := 'nomination/gas_day_end';
|
|
g_xml_fields(4).mandatory_flag := TRUE;
|
|
g_xml_fields(5).node_name := 'nomination/language';
|
|
g_xml_fields(5).mandatory_flag := TRUE;
|
|
g_xml_fields(6).node_name := 'nomination/nomination_body';
|
|
g_xml_fields(6).mandatory_flag := TRUE;
|
|
g_xml_fields(7).node_name := 'nomination/nomination_body/nomination_line';
|
|
g_xml_fields(7).mandatory_flag := TRUE;
|
|
|
|
g_nom_fields(1).node_name := 'gas_day';
|
|
g_nom_fields(1).mandatory_flag := TRUE;
|
|
g_nom_fields(2).node_name := 'network_point_code';
|
|
g_nom_fields(2).mandatory_flag := TRUE;
|
|
g_nom_fields(3).node_name := 'category_code';
|
|
g_nom_fields(3).mandatory_flag := TRUE;
|
|
g_nom_fields(4).node_name := 'value';
|
|
g_nom_fields(4).mandatory_flag := TRUE;
|
|
|
|
END efno_xml_interface;
|
|
/
|