3517 lines
143 KiB
Plaintext
3517 lines
143 KiB
Plaintext
CREATE OR REPLACE PACKAGE BODY efno_rules AS
|
|
--
|
|
--
|
|
PROCEDURE evaluate_rule_sql( p_sql IN VARCHAR2
|
|
, p_success IN OUT BOOLEAN
|
|
, p_no_data OUT BOOLEAN
|
|
, p_return_value OUT NUMBER )
|
|
IS
|
|
-- Dynamic SQL local variables
|
|
l_cursor INTEGER;
|
|
l_cursor_count INTEGER;
|
|
l_cursor_dummy INTEGER;
|
|
--
|
|
BEGIN
|
|
--
|
|
-- htp.p(p_sql);
|
|
--caco_debug.putline('SP: efno_rules.evaluate_rule_sql p_sql: '||p_sql);
|
|
--
|
|
p_no_data := FALSE;
|
|
--
|
|
l_cursor := DBMS_SQL.OPEN_CURSOR;
|
|
DBMS_SQL.PARSE( l_cursor, p_sql, DBMS_SQL.NATIVE );
|
|
DBMS_SQL.DEFINE_COLUMN( l_cursor, 1, p_return_value );
|
|
--
|
|
l_cursor_dummy := DBMS_SQL.EXECUTE( l_cursor );
|
|
--
|
|
-- Get the number of rows returned - one is good - all else is bad
|
|
l_cursor_count := DBMS_SQL.FETCH_ROWS( l_cursor );
|
|
--
|
|
IF l_cursor_count = 1 THEN
|
|
-- Put the column value into the return value
|
|
DBMS_SQL.COLUMN_VALUE( l_cursor, 1, p_return_value );
|
|
--
|
|
ELSIF l_cursor_count = 0 THEN
|
|
p_success := FALSE;
|
|
p_no_data := TRUE;
|
|
caco_debug.putline('efno_rules.evaluate_rule_sql : Error : '||chr(10)
|
|
||'No data found'||chr(10)||'SQL: '||p_sql);
|
|
ELSE
|
|
p_success := FALSE;
|
|
caco_debug.putline('efno_rules.evaluate_rule_sql : Error : '||chr(10)
|
|
||'Too Many Rows');
|
|
END IF;
|
|
--
|
|
-- Close the cursor
|
|
DBMS_SQL.CLOSE_CURSOR( l_cursor );
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
p_success := FALSE;
|
|
caco_debug.putline('efno_rules.evaluate_rule_sql : Error : '
|
|
||chr(10)||p_sql||chr(10)
|
|
||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.evaluate_rule_sql');
|
|
--
|
|
END evaluate_rule_sql;
|
|
--
|
|
--
|
|
--
|
|
--
|
|
|
|
FUNCTION valid_category( p_template_id IN NUMBER
|
|
, p_contract_id IN NUMBER
|
|
, p_temp_code IN VARCHAR2
|
|
, p_category_id OUT NUMBER )
|
|
RETURN BOOLEAN
|
|
IS
|
|
--
|
|
-- Ensure that the category exists
|
|
CURSOR c_category IS
|
|
SELECT cate_id
|
|
FROM categories
|
|
WHERE UPPER( code ) = UPPER( p_temp_code );
|
|
--
|
|
-- Ensure that that the category exists for the given contract
|
|
CURSOR c_contract_cat IS
|
|
SELECT cate.cate_id
|
|
FROM categories cate
|
|
, contract_categories coca
|
|
WHERE cate.cate_id = coca.cate_id
|
|
AND UPPER(cate.code) = UPPER(p_temp_code)
|
|
AND coca.cont_id = p_contract_id;
|
|
--
|
|
-- Ensure that that the category exists for the given contract template
|
|
CURSOR c_template_cat IS
|
|
SELECT cate.cate_id
|
|
FROM categories cate
|
|
, contract_template_categories cotc
|
|
WHERE cate.cate_id = cotc.cate_id
|
|
AND UPPER(cate.code) = UPPER(p_temp_code)
|
|
AND cotc.cote_id = p_template_id;
|
|
--
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
--
|
|
IF p_template_id IS NOT NULL AND p_template_id > 0 THEN
|
|
--
|
|
-- Check that the code exists for the template
|
|
OPEN c_template_cat;
|
|
FETCH c_template_cat INTO p_category_id;
|
|
--
|
|
IF c_template_cat%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_template_cat;
|
|
--
|
|
ELSIF p_contract_id IS NOT NULL AND p_contract_id > 0 THEN
|
|
--
|
|
-- Check that the code exists for the contract
|
|
OPEN c_contract_cat;
|
|
FETCH c_contract_cat INTO p_category_id;
|
|
--
|
|
IF c_contract_cat%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_contract_cat;
|
|
--
|
|
ELSE
|
|
--
|
|
-- Check that the code exists
|
|
OPEN c_category;
|
|
FETCH c_category INTO p_category_id;
|
|
--
|
|
IF c_category%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_category;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END valid_category;
|
|
|
|
|
|
|
|
|
|
FUNCTION valid_parameter( p_template_id IN NUMBER
|
|
, p_contract_id IN NUMBER
|
|
, p_temp_code IN VARCHAR2
|
|
, p_parameter_id OUT NUMBER )
|
|
RETURN BOOLEAN
|
|
IS
|
|
--
|
|
-- Ensure that the Parameter Exists
|
|
CURSOR c_parameter IS
|
|
SELECT pars_id
|
|
FROM parameters
|
|
WHERE UPPER( code ) = UPPER( p_temp_code );
|
|
--
|
|
-- Ensure that that the parameter exists for the given contract
|
|
CURSOR c_contract_par IS
|
|
SELECT pars.pars_id
|
|
FROM parameters pars
|
|
, contract_parameters copa
|
|
WHERE pars.pars_id = copa.pars_id
|
|
AND UPPER(pars.code) = UPPER(p_temp_code)
|
|
AND copa.cont_id = p_contract_id;
|
|
--
|
|
-- Ensure that that the parameter exists for the given contract template
|
|
CURSOR c_template_par IS
|
|
SELECT pars.pars_id
|
|
FROM parameters pars
|
|
, contract_template_params cotp
|
|
WHERE pars.pars_id = cotp.pars_id
|
|
AND UPPER(pars.code) = UPPER(p_temp_code)
|
|
AND cotp.cote_id = p_template_id;
|
|
--
|
|
-- If not a standalone parameter - is the parameter automatically inherited from a category?
|
|
CURSOR c_template_cate_par IS
|
|
SELECT pars.pars_id
|
|
FROM parameters pars
|
|
, categories cate
|
|
, contract_template_categories cotc
|
|
WHERE cotc.cote_id = p_template_id
|
|
AND cotc.cate_id = cate.cate_id
|
|
AND pars.cate_id = cate.cate_id
|
|
AND UPPER(pars.code) = UPPER(p_temp_code);
|
|
--
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
--
|
|
IF p_template_id IS NOT NULL AND p_template_id > 0 THEN
|
|
--
|
|
-- Check that the code exists for the template
|
|
-- Firstly see if this will be an automatically inherited parameter (from a category)
|
|
--
|
|
OPEN c_template_cate_par;
|
|
FETCH c_template_cate_par INTO p_parameter_id;
|
|
--
|
|
IF c_template_cate_par%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_template_cate_par;
|
|
--
|
|
-- If it isn't automatically inherited - check if it is a standalone parameter
|
|
IF NOT l_success THEN
|
|
--
|
|
OPEN c_template_par;
|
|
FETCH c_template_par INTO p_parameter_id;
|
|
--
|
|
IF c_template_par%FOUND THEN
|
|
l_success := TRUE;
|
|
END IF;
|
|
CLOSE c_template_par;
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
ELSIF p_contract_id IS NOT NULL AND p_contract_id > 0 THEN
|
|
--
|
|
-- Check that the code exists for the contract
|
|
OPEN c_contract_par;
|
|
FETCH c_contract_par INTO p_parameter_id;
|
|
--
|
|
IF c_contract_par%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_contract_par;
|
|
--
|
|
ELSE
|
|
--
|
|
-- Check that the code exists
|
|
OPEN c_parameter;
|
|
FETCH c_parameter INTO p_parameter_id;
|
|
--
|
|
IF c_parameter%NOTFOUND THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
CLOSE c_parameter;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END valid_parameter;
|
|
|
|
FUNCTION valid_npgp(p_contract_id IN NUMBER
|
|
,p_temp_code IN VARCHAR2)
|
|
RETURN BOOLEAN
|
|
IS
|
|
--
|
|
-- Ensure that that the network point group parameter exists for the given contract
|
|
CURSOR c_npgp IS
|
|
SELECT 'X'
|
|
FROM network_point_gp_params npgp
|
|
WHERE UPPER(npgp.code) = UPPER(p_temp_code)
|
|
AND npgp.cont_id = p_contract_id;
|
|
--
|
|
l_success BOOLEAN := FALSE;
|
|
l_dummy VARCHAR2(1);
|
|
--
|
|
BEGIN
|
|
--
|
|
IF p_contract_id IS NOT NULL AND p_contract_id > 0 THEN
|
|
--
|
|
-- Check that the network point group parameter exists for the contract
|
|
OPEN c_npgp;
|
|
FETCH c_npgp INTO l_dummy;
|
|
--
|
|
IF c_npgp%FOUND THEN
|
|
l_success := TRUE;
|
|
END IF;
|
|
CLOSE c_npgp;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END valid_npgp;
|
|
|
|
--
|
|
/**
|
|
-- FUNCTION rule_text --
|
|
-- Validates one side of a rule defined through the EFT Nominations Web interface
|
|
-- and optionally returns the various parts of the required SQL statement for running the rules
|
|
-- <b>Note : </b>Once passed back to the calling routine, if the hours_in_gas_day function has
|
|
-- been included in the text, a further substitution to replace 'p_gas_day' must take place
|
|
--
|
|
-- %param p_text The stored text of one side of the rule to be evaluated
|
|
-- %param p_rule_type SHEET or ROW rule (changes how it is validated)
|
|
-- %param p_select The evaluated SQL for the first part of the SQL select statement
|
|
-- %param p_from The evaluated SQL for the FROM clause
|
|
-- %param p_where The evaluated SQL for the WHERE clause
|
|
-- %param p_nnpcv_tab Table of Nom Net Point Cat Vals - ID and COCA and CONP id
|
|
-- %param p_contract_id The unique identifier of the the contract for which this nomination is for
|
|
-- %param p_conf_id The Unique Identifier of the specific confirmation being validated for this rule
|
|
-- %param p_nomination_id The unique identifier for the specific nomination being validated for this rule
|
|
-- %param p_net_point_id The Unique Identifier of a Network Point - for ROW rules
|
|
-- %param p_gas_day For Row Rules, Each Network point requires a category value for each gas day
|
|
-- %param p_parse_only TRUE if we only want to see if the rule is syntactically valid
|
|
-- %param p_force_conf TRUE if the rule_text function is being called whilst forcing a confirmation
|
|
-- Will ensure that a list of nnpcv items are returned in p_nnpcv_tab
|
|
-- %param p_return_error OUT parameter containing an error message if things have gone wrong
|
|
--
|
|
-- %return BOOLEAN TRUE indicating that the passed text is valid syntactically
|
|
*/
|
|
FUNCTION rule_text ( p_text IN VARCHAR2
|
|
, p_rule_type IN VARCHAR2
|
|
, p_select OUT VARCHAR2
|
|
, p_from OUT VARCHAR2
|
|
, p_where OUT VARCHAR2
|
|
, p_nnpcv_tab IN OUT NOCOPY efno_confirmations.nnpcv_tab
|
|
, p_template_id IN contract_templates.cote_id%TYPE DEFAULT 0
|
|
, p_contract_id IN contracts.cont_id%TYPE DEFAULT 0
|
|
, p_conf_id IN confirmations.conf_id%TYPE DEFAULT 0
|
|
, p_nomination_id IN nominations.nomi_id%TYPE DEFAULT 0
|
|
, p_net_point_id IN network_points.nepo_id%TYPE DEFAULT 0
|
|
, p_gas_day IN DATE DEFAULT NULL
|
|
, p_parse_only IN BOOLEAN DEFAULT FALSE -- MUST NOT be TRUE if p_force_conf is TRUE
|
|
, p_force_conf IN BOOLEAN DEFAULT FALSE -- MUST NOT be TRUE if p_parse_only is TRUE
|
|
, p_return_error OUT VARCHAR2 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
-- Network point ID finder
|
|
CURSOR c_network_point( cp_code IN VARCHAR2 ) IS
|
|
SELECT nepo_id
|
|
FROM network_points
|
|
WHERE UPPER( code ) = UPPER( cp_code );
|
|
--
|
|
-- Network point group ID finder
|
|
CURSOR c_network_point_group( cp_code IN VARCHAR2 ) IS
|
|
SELECT nepg_id
|
|
FROM network_point_groups
|
|
WHERE UPPER( code ) = UPPER( cp_code );
|
|
--
|
|
-- Cursor to find the Contract Network Point ID
|
|
CURSOR c_conp( cp_cont_id IN NUMBER
|
|
, cp_nepo_id IN NUMBER )
|
|
IS
|
|
SELECT conp_id
|
|
FROM cont_network_points
|
|
WHERE cont_id = cp_cont_id
|
|
AND nepo_id = cp_nepo_id;
|
|
--
|
|
-- Cursor to find the active Contract Network Point IDs for an active network point group
|
|
CURSOR c_conp_nepg( cp_cont_id IN NUMBER
|
|
, cp_nepg_id IN NUMBER )
|
|
IS
|
|
SELECT conp_id
|
|
FROM cont_network_points conp,
|
|
network_point_mappings nepm,
|
|
network_point_groups nepg,
|
|
network_points nepo
|
|
WHERE conp.cont_id = cp_cont_id
|
|
AND nepm.nepg_id = cp_nepg_id
|
|
AND nepm.nepo_id = conp.nepo_id
|
|
AND conp.nepo_id = nepo.nepo_id
|
|
AND nepg.nepg_id = cp_nepg_id
|
|
AND nepo.status = 'A'
|
|
AND nepg.status = 'A';
|
|
--
|
|
-- Cursor to find the Contract Category ID
|
|
CURSOR c_coca( cp_cont_id IN NUMBER
|
|
, cp_cate_id IN NUMBER )
|
|
IS
|
|
SELECT coca_id
|
|
FROM contract_categories
|
|
WHERE cont_id = cp_cont_id
|
|
AND cate_id = cp_cate_id;
|
|
--
|
|
-- Cursor to find the Contract Parameter ID
|
|
CURSOR c_copa( cp_cont_id IN NUMBER
|
|
, cp_pars_id IN NUMBER )
|
|
IS
|
|
SELECT copa_id
|
|
FROM contract_parameters
|
|
WHERE cont_id = cp_cont_id
|
|
AND pars_id = cp_pars_id;
|
|
--
|
|
-- Cursor to get the conf_net_point_cat_val ID
|
|
CURSOR c_nnpcv( cp_coca_id IN NUMBER
|
|
, cp_conp_id IN NUMBER )
|
|
IS
|
|
SELECT nnpcv_id
|
|
FROM conf_net_point_cat_vals
|
|
WHERE conf_id = p_conf_id
|
|
AND coca_id = cp_coca_id
|
|
AND conp_id = cp_conp_id;
|
|
--
|
|
-- Cursor to the conf_net_point_cat_val ID for the given gas day..
|
|
CURSOR c_nnpcv_row( cp_coca_id IN NUMBER
|
|
, cp_conp_id IN NUMBER
|
|
, cp_gas_day IN DATE )
|
|
IS
|
|
SELECT nnpcv_id
|
|
FROM conf_net_point_cat_vals
|
|
WHERE conf_id = p_conf_id
|
|
AND coca_id = cp_coca_id
|
|
AND conp_id = cp_conp_id
|
|
AND gas_day = cp_gas_day;
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
l_code_pos VARCHAR2(4) := '0000';
|
|
--
|
|
l_text_length NUMBER := LENGTH(p_text);
|
|
l_position NUMBER := 0;
|
|
l_token_type VARCHAR2(1) := 'X';
|
|
l_token_close_pos NUMBER := 0;
|
|
l_token_code VARCHAR2(70) := NULL;
|
|
l_temp_code parameters.code%TYPE := NULL;
|
|
l_tokens_found NUMBER := 0;
|
|
l_brace_counter NUMBER := 0;
|
|
l_count_nnpcv NUMBER := 0;
|
|
l_nnpcv_id nom_net_point_cat_vals.nnpcv_id%TYPE;
|
|
--
|
|
l_parameter_id NUMBER := 0;
|
|
l_category_id NUMBER := 0;
|
|
l_network_point_id NUMBER := 0;
|
|
l_temp_alias VARCHAR2(50) := NULL;
|
|
l_conp_id cont_network_points.conp_id%TYPE;
|
|
l_coca_id contract_categories.coca_id%TYPE;
|
|
l_copa_id contract_parameters.copa_id%TYPE;
|
|
l_nepg_id NUMBER := 0;
|
|
--
|
|
previous_was_token BOOLEAN := FALSE;
|
|
previous_was_open_brace BOOLEAN := FALSE;
|
|
previous_was_close_brace BOOLEAN := FALSE;
|
|
previous_was_operator BOOLEAN := FALSE;
|
|
previous_was_value BOOLEAN := FALSE;
|
|
previous_was_period BOOLEAN := FALSE;
|
|
space_encountered BOOLEAN := FALSE;
|
|
first_item_found BOOLEAN := TRUE;
|
|
valid_token BOOLEAN := TRUE;
|
|
missing_nnpcv BOOLEAN := FALSE;
|
|
--
|
|
l_current_char VARCHAR2(1);
|
|
--
|
|
l_conp_nepg_count NUMBER := 0;
|
|
l_conp_ids VARCHAR2(2000) := NULL;
|
|
l_npgp_code VARCHAR2(50) := NULL;
|
|
--
|
|
BEGIN
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text START');
|
|
IF l_text_length > 0 THEN
|
|
--
|
|
--caco_debug.putline('Text Length '||l_text_length||' : '||p_text);
|
|
p_select := NULL;
|
|
l_count_nnpcv := NVL(p_nnpcv_tab.COUNT,0);
|
|
l_position := 1;
|
|
l_code_pos := '0010';
|
|
--
|
|
<<rule_text_loop>>
|
|
WHILE l_position <= l_text_length LOOP
|
|
--
|
|
valid_token := FALSE;
|
|
l_temp_alias := NULL;
|
|
l_token_type := 'X';
|
|
l_token_code := NULL;
|
|
l_token_close_pos := 0;
|
|
l_category_id := 0;
|
|
l_parameter_id := 0;
|
|
l_network_point_id := 0;
|
|
l_temp_code := NULL;
|
|
l_conp_id := 0;
|
|
l_coca_id := 0;
|
|
l_copa_id := 0;
|
|
l_current_char := SUBSTR( p_text, l_position, 1 );
|
|
--
|
|
l_nepg_id := 0;
|
|
l_conp_nepg_count := 0;
|
|
l_conp_ids := NULL;
|
|
l_npgp_code := NULL;
|
|
--
|
|
l_code_pos := '0020';
|
|
--
|
|
<<my_case>>
|
|
CASE
|
|
WHEN l_current_char = ' ' THEN
|
|
l_code_pos := '0030';
|
|
l_position := l_position + 1;
|
|
space_encountered := TRUE;
|
|
--
|
|
IF NOT p_parse_only THEN
|
|
p_select := p_select||l_current_char;
|
|
END IF;
|
|
--
|
|
WHEN l_current_char = '$' THEN
|
|
--
|
|
l_code_pos := '0040';
|
|
--
|
|
l_nnpcv_id := 0;
|
|
--
|
|
-- Ensure that the previous found item was not a token
|
|
IF previous_was_token
|
|
OR previous_was_value
|
|
OR previous_was_period
|
|
OR previous_was_close_brace
|
|
THEN
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : Previous item was a token');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
-- We have the start of a token - get the rest of it.
|
|
--
|
|
IF SUBSTR( p_text, l_position + 1, 1 ) != '<' THEN
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : < (doesnt exist - illformed token)');
|
|
-- Not a well formed token
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
-- Get the next '>' symbol (closure of the token)
|
|
l_token_close_pos := INSTR( p_text, '>', 1, l_tokens_found + 1);
|
|
l_token_code := SUBSTR( p_text, l_position + 2, l_token_close_pos - l_position - 2 );
|
|
--caco_debug.putline('l_token_code: '||l_token_code);
|
|
--
|
|
IF l_token_code = 'hours_in_gas_day' THEN
|
|
IF NOT p_parse_only THEN
|
|
-- Just add call to common utility function to the return SQL text
|
|
p_select := p_select||'cout_dates.hours_in_gas_day(p_gas_day)';
|
|
END IF;
|
|
ELSE
|
|
--
|
|
l_code_pos := '0050';
|
|
--
|
|
-- All other substitutable tokens - must check for "Network Point" and apply alias
|
|
-- to additional nomination or Network Point Parameters table if necessary
|
|
IF UPPER(p_rule_type) = 'SHEET' THEN
|
|
--
|
|
-- This should be a specific Network Point with concatenated token
|
|
-- Check the name in network Points table
|
|
--caco_debug.putline('SP: efno_rules.rule_text 010');
|
|
OPEN c_network_point( SUBSTR( l_token_code, 1, INSTR( l_token_code, '.' ) - 1 ) );
|
|
FETCH c_network_point INTO l_network_point_id;
|
|
IF c_network_point%FOUND THEN
|
|
--
|
|
CLOSE c_network_point;
|
|
--
|
|
-- get the CONP_ID for the given network point and contract
|
|
OPEN c_conp( p_contract_id
|
|
, l_network_point_id );
|
|
FETCH c_conp INTO l_conp_id;
|
|
IF c_conp%FOUND THEN
|
|
CLOSE c_conp;
|
|
ELSE
|
|
-- Bit of a strange problem.
|
|
CLOSE c_conp;
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : SHEET rule '
|
|
||' Network Point not found for Contract');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
CLOSE c_network_point;
|
|
-- not a network point so check the name in the network point groups table
|
|
OPEN c_network_point_group( SUBSTR( l_token_code, 1, INSTR( l_token_code, '.' ) - 1 ) );
|
|
FETCH c_network_point_group INTO l_nepg_id;
|
|
IF c_network_point_group%FOUND THEN
|
|
CLOSE c_network_point_group;
|
|
-- get the CONP_IDs in a string for the given network point group and contract
|
|
FOR r IN c_conp_nepg( p_contract_id
|
|
, l_nepg_id ) LOOP
|
|
IF l_conp_nepg_count = 0 THEN
|
|
l_conp_ids := r.conp_id;
|
|
ELSE
|
|
l_conp_ids := l_conp_ids||','||r.conp_id;
|
|
END IF;
|
|
l_conp_nepg_count := l_conp_nepg_count + 1;
|
|
END LOOP;
|
|
-- if no network points found for contract/nepg then add dummy conp_id so evalution will be 0
|
|
-- and the rule will be redundant
|
|
IF l_conp_nepg_count = 0 THEN
|
|
l_conp_ids := '0';
|
|
END IF;
|
|
--caco_debug.putline('SP: l_conp_ids: '||l_conp_ids);
|
|
--
|
|
ELSE
|
|
CLOSE c_network_point_group;
|
|
-- Network point/network point group does not exist so the text is invalid
|
|
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : SHEET rule - invalid network point/nepg : ~'||l_token_code||'~');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
END IF;
|
|
l_temp_code := SUBSTR( l_token_code, INSTR( l_token_code, '.' ) + 1 );
|
|
--
|
|
ELSE -- ROW
|
|
--caco_debug.putline('SP: efno_rules.rule_text 020');
|
|
-- get the CONP_ID for the given network point and contract
|
|
IF p_net_point_id IS NOT NULL
|
|
AND p_net_point_id > 0
|
|
THEN
|
|
--caco_debug.putline('Network Point: '||p_net_point_id);
|
|
OPEN c_conp( p_contract_id
|
|
, p_net_point_id );
|
|
FETCH c_conp INTO l_conp_id;
|
|
IF c_conp%FOUND THEN
|
|
CLOSE c_conp;
|
|
--caco_debug.putline('conp: '||l_conp_id);
|
|
ELSE
|
|
-- Bit of a strange problem.
|
|
CLOSE c_conp;
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : ROW rule '
|
|
||' Network Point not found for Contract'
|
|
||chr(10)||p_contract_id
|
|
||chr(10)||p_net_point_id);
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
ELSIF NOT p_parse_only OR p_force_conf THEN
|
|
-- What to do here - we weren't given a network point so we are stuck
|
|
-- A ROW rule can only be evaluated for a given Network Point
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : ROW rule (not parsing) :'
|
|
||' Network Point not provided for ROW rule for Contract'
|
|
||chr(10)||p_contract_id );
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
--
|
|
END IF;
|
|
--
|
|
l_temp_code := l_token_code;
|
|
END IF;
|
|
--
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 040');
|
|
-- Check if the token is a valid category for the given contract/template (or none)
|
|
IF efno_rules.valid_category( p_template_id
|
|
, p_contract_id
|
|
, l_temp_code
|
|
, l_category_id )
|
|
THEN
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 050');
|
|
l_token_type := 'C';
|
|
--
|
|
IF NOT p_parse_only
|
|
AND NVL(p_contract_id,0) > 0
|
|
THEN
|
|
-- Need to get the COCA_ID for the Contract
|
|
OPEN c_coca( p_contract_id
|
|
, l_category_id );
|
|
FETCH c_coca INTO l_coca_id;
|
|
IF c_coca%FOUND THEN
|
|
CLOSE c_coca;
|
|
ELSE
|
|
CLOSE c_coca;
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : Unable to find Contract Category : '||l_temp_code);
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
END IF;
|
|
--
|
|
valid_token := TRUE;
|
|
--
|
|
ELSE
|
|
-- Check if it is a parameter
|
|
IF efno_rules.valid_parameter( p_template_id
|
|
, p_contract_id
|
|
, l_temp_code
|
|
, l_parameter_id )
|
|
THEN
|
|
--caco_debug.putline('Parameter found: '||l_parameter_id);
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 070');
|
|
l_token_type := 'P';
|
|
--
|
|
IF NOT p_parse_only
|
|
AND NVL(p_contract_id,0) > 0
|
|
THEN
|
|
--caco_debug.putline('Looking for copa!');
|
|
-- Need to get the COPA_ID for the contract
|
|
OPEN c_copa( p_contract_id
|
|
, l_parameter_id );
|
|
FETCH c_copa INTO l_copa_id;
|
|
IF c_copa%FOUND THEN
|
|
CLOSE c_copa;
|
|
--caco_debug.putline('Found copa: '||l_copa_id);
|
|
ELSE
|
|
CLOSE c_copa;
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : Unable to find Contract Parameter : '||l_temp_code);
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
END IF;
|
|
--
|
|
valid_token := TRUE;
|
|
--
|
|
ELSE
|
|
--
|
|
--Check if it is a network point group parameter
|
|
IF valid_npgp(p_contract_id
|
|
,l_temp_code)
|
|
THEN
|
|
l_token_type := 'N';
|
|
valid_token := TRUE;
|
|
l_npgp_code := l_temp_code;
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 080');
|
|
IF ( valid_token AND NOT p_parse_only ) -- If its a valid token and we are NOT parsing
|
|
OR ( valid_token AND p_force_conf ) -- valid token and forcing a confirmation
|
|
THEN
|
|
--caco_debug.putline('SP: efno_rules.rule_text 090');
|
|
--
|
|
IF l_token_type = 'C' THEN
|
|
--caco_debug.putline('SP: efno_rules.rule_text 091');
|
|
--
|
|
l_code_pos := '0060';
|
|
--
|
|
-- Apply network point alias
|
|
IF p_force_conf THEN
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 092');
|
|
-- forcing a confirmation (due to errors)
|
|
--
|
|
l_temp_alias := 'cnpcv'||l_conp_id||'x'||l_coca_id;
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_from := 'dual';
|
|
ELSE
|
|
p_from := p_from ||' , conf_net_point_cat_vals '||l_temp_alias;
|
|
p_where := p_where||' AND '||l_temp_alias||'.conf_id = '||p_conf_id;
|
|
END IF;
|
|
--
|
|
-- Lets get the nnpcv_id as we will need this to return
|
|
l_count_nnpcv := l_count_nnpcv + 1;
|
|
--
|
|
IF p_rule_type = 'SHEET' THEN
|
|
IF l_conp_ids IS NULL THEN
|
|
OPEN c_nnpcv( l_coca_id, l_conp_id );
|
|
FETCH c_nnpcv INTO l_nnpcv_id;
|
|
IF c_nnpcv%NOTFOUND THEN
|
|
-- Houston we have a problem - Contract must have changed.
|
|
-- Now we need the conp and coca but should indicate that the data is missing
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||'l_coca_id: '||l_coca_id||' l_conp_id: '||l_conp_id||' : Case : Unable to find Nom Net Point Cat Val ID');
|
|
l_success := FALSE;
|
|
missing_nnpcv := TRUE;
|
|
p_nnpcv_tab(l_count_nnpcv).missing := 'Y';
|
|
--
|
|
END IF;
|
|
CLOSE c_nnpcv;
|
|
END IF;
|
|
ELSE
|
|
OPEN c_nnpcv_row( l_coca_id, l_conp_id, p_gas_day );
|
|
FETCH c_nnpcv_row INTO l_nnpcv_id;
|
|
IF c_nnpcv_row%NOTFOUND THEN
|
|
-- Houston we have a problem - Contract must have changed.
|
|
-- Now we need the conp and coca but should indicate that the data is missing
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : Unable to find Nom Net Point Cat Val ID');
|
|
l_success := FALSE;
|
|
missing_nnpcv := TRUE;
|
|
p_nnpcv_tab(l_count_nnpcv).missing := 'Y';
|
|
--
|
|
END IF;
|
|
CLOSE c_nnpcv_row;
|
|
END IF;
|
|
--
|
|
p_nnpcv_tab(l_count_nnpcv).nnpcv_id := l_nnpcv_id;
|
|
p_nnpcv_tab(l_count_nnpcv).coca_id := l_coca_id;
|
|
p_nnpcv_tab(l_count_nnpcv).conp_id := l_conp_id;
|
|
p_nnpcv_tab(l_count_nnpcv).gas_day := p_gas_day;
|
|
--
|
|
ELSE
|
|
-- validating a nomination
|
|
--caco_debug.putline('SP: efno_rules.rule_text 093');
|
|
l_temp_alias := 'nnpcv'||l_conp_id||'x'||l_coca_id;
|
|
-- check if there is a nepg involved
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_from := 'dual';
|
|
ELSE
|
|
p_from := p_from ||' , nom_net_point_cat_vals '||l_temp_alias;
|
|
--
|
|
-- Add additional tables to translate nominations accross contracts
|
|
--
|
|
p_from := p_from || ' , cont_network_points cnp1_'||l_conp_id||'x'||l_coca_id||' , cont_network_points cnp2_'||l_conp_id||'x'||l_coca_id||' , contract_categories cc1_'||l_conp_id||'x'||l_coca_id||' , contract_categories cc2_'||l_conp_id||'x'||l_coca_id||' ';
|
|
--
|
|
END IF;
|
|
p_nnpcv_tab(l_count_nnpcv).coca_id := l_coca_id;
|
|
-- p_nnpcv_tab(l_count_nnpcv).conp_id := l_conp_id;
|
|
p_nnpcv_tab(l_count_nnpcv).gas_day := p_gas_day;
|
|
--
|
|
END IF;
|
|
--
|
|
IF p_from NOT LIKE '% cnp1_%' THEN
|
|
IF p_nomination_id IS NOT NULL THEN
|
|
--caco_debug.putline('SP: efno_rules.rule_text 094');
|
|
-- check if there is a nepg involved
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_where := NULL;
|
|
ELSE
|
|
p_where := p_where||' AND '||l_temp_alias||'.conp_id = '||l_conp_id
|
|
||' AND '||l_temp_alias||'.coca_id = '||l_coca_id
|
|
||' AND '||l_temp_alias||'.nomi_id = '||p_nomination_id
|
|
||' AND '||l_temp_alias||'.gas_day = p_gas_day';
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--caco_debug.putline('SP: efno_rules.rule_text 095');
|
|
-- check if there is a nepg involved
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_where := NULL;
|
|
ELSE
|
|
p_where := p_where||' AND '||l_temp_alias||'.conp_id = '||l_conp_id
|
|
||' AND '||l_temp_alias||'.coca_id = '||l_coca_id
|
|
||' AND '||l_temp_alias||'.gas_day = p_gas_day';
|
|
END IF;
|
|
--
|
|
END IF;
|
|
ELSE
|
|
--caco_debug.putline('SP: efno_rules.rule_text 096');
|
|
-- check if there is a nepg involved
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_where := NULL;
|
|
ELSE
|
|
p_where := p_where || 'AND cc1_'||l_conp_id||'x'||l_coca_id||'.cate_id = cc2_'||l_conp_id||'x'||l_coca_id||'.cate_id
|
|
AND cnp1_'||l_conp_id||'x'||l_coca_id||'.nepo_id = cnp2_'||l_conp_id||'x'||l_coca_id||'.nepo_id
|
|
AND cc1_'||l_conp_id||'x'||l_coca_id||'.coca_id = '||l_coca_id||'
|
|
AND cc2_'||l_conp_id||'x'||l_coca_id||'.coca_id = '||l_temp_alias||'.coca_id
|
|
AND cnp1_'||l_conp_id||'x'||l_coca_id||'.conp_id = '||l_conp_id||'
|
|
AND cnp2_'||l_conp_id||'x'||l_coca_id||'.conp_id = '||l_temp_alias||'.conp_id
|
|
AND '||l_temp_alias||'.nomi_id = '||p_nomination_id||'
|
|
AND '||l_temp_alias||'.gas_day = p_gas_day';
|
|
END IF;
|
|
END IF;
|
|
-- check if there is a nepg involved
|
|
IF l_conp_ids IS NOT NULL THEN
|
|
p_select := p_select||'efno_rules.get_nepg_value('||NVL(p_nomination_id,0)||', '||l_nepg_id||' ,'||l_coca_id||' ,'||p_conf_id||' ,p_gas_day)';
|
|
ELSE
|
|
p_select := p_select||l_temp_alias||'.value';
|
|
END IF;
|
|
--
|
|
ELSIF l_token_type = 'P' THEN -- token is parameter
|
|
--caco_debug.putline('SP: efno_rules.rule_text 099');
|
|
--
|
|
l_code_pos := '0070';
|
|
--
|
|
l_temp_alias := 'cnppv'||l_conp_id||'x'||l_copa_id;
|
|
p_from := p_from ||' , cont_net_point_param_vals '||l_temp_alias;
|
|
--
|
|
p_where := p_where||' AND '||l_temp_alias||'.conp_id = '||l_conp_id
|
|
||' AND '||l_temp_alias||'.copa_id = '||l_copa_id;
|
|
--
|
|
p_select := p_select||'efno_interruption.get_int_val('||l_temp_alias||'.value, '||l_conp_id||', '||l_copa_id||', p_gas_day)';
|
|
--
|
|
ELSE -- token is a network point group parameter(npgp)
|
|
--caco_debug.putline('SP: efno_rules.rule_text 100');
|
|
--
|
|
l_code_pos := '0075';
|
|
--
|
|
p_from := 'dual';
|
|
--
|
|
p_where := NULL;
|
|
p_select := p_select||'efno_rules.get_npgp_value('||p_contract_id||', '||l_nepg_id||')';
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF p_parse_only
|
|
AND valid_token
|
|
THEN
|
|
--caco_debug.putline('SP: efno_rules.rule_text 105');
|
|
-- Just parsing, token is Valid, move on
|
|
NULL;
|
|
ELSE -- Not a valid token
|
|
--
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : invalid token : ~'||l_temp_code||'~');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
--
|
|
END IF;
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('SP: efno_rules.rule_text 110');
|
|
l_code_pos := '0080';
|
|
--
|
|
previous_was_open_brace := FALSE;
|
|
previous_was_close_brace := FALSE;
|
|
previous_was_token := TRUE;
|
|
previous_was_operator := FALSE;
|
|
previous_was_value := FALSE;
|
|
previous_was_period := FALSE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
l_tokens_found := l_tokens_found + 1;
|
|
l_position := l_position + ( l_token_close_pos - l_position ) + 1;
|
|
--
|
|
WHEN l_current_char IN ('0','1','2','3','4','5','6','7','8','9','0') THEN
|
|
--
|
|
l_code_pos := '0100';
|
|
--
|
|
IF ( ( previous_was_value OR previous_was_period ) AND space_encountered )
|
|
OR previous_was_token
|
|
OR previous_was_close_brace
|
|
THEN
|
|
-- Cant have a value followed by a space followed by a value
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position||' : Case : invalid value');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
previous_was_open_brace := FALSE;
|
|
previous_was_close_brace := FALSE;
|
|
previous_was_token := FALSE;
|
|
previous_was_operator := FALSE;
|
|
previous_was_value := TRUE;
|
|
previous_was_period := FALSE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
IF NOT p_parse_only THEN
|
|
p_select := p_select||l_current_char;
|
|
END IF;
|
|
--
|
|
l_position := l_position + 1;
|
|
--
|
|
WHEN l_current_char = '.' THEN
|
|
--
|
|
l_code_pos := '0110';
|
|
--
|
|
IF previous_was_token
|
|
OR previous_was_close_brace
|
|
OR previous_was_period
|
|
OR ( previous_was_value AND space_encountered )
|
|
THEN
|
|
-- Period can only be preceded by a space, an open brace or an operator
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : badly positioned period');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
previous_was_open_brace := FALSE;
|
|
previous_was_close_brace := FALSE;
|
|
previous_was_token := FALSE;
|
|
previous_was_operator := FALSE;
|
|
previous_was_value := FALSE;
|
|
previous_was_period := TRUE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
p_select := p_select||l_current_char;
|
|
l_position := l_position + 1;
|
|
--
|
|
WHEN l_current_char IN ('+','-','*','/') THEN
|
|
--
|
|
l_code_pos := '0120';
|
|
--
|
|
-- Operator (excluding braces)
|
|
IF previous_was_operator
|
|
OR previous_was_open_brace
|
|
OR first_item_found
|
|
THEN
|
|
-- Operator must be preceded by a token or a value or a closing brace
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : badly positioned operator');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
previous_was_open_brace := FALSE;
|
|
previous_was_close_brace := FALSE;
|
|
previous_was_token := FALSE;
|
|
previous_was_operator := TRUE;
|
|
previous_was_value := FALSE;
|
|
previous_was_period := FALSE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
IF NOT p_parse_only THEN
|
|
p_select := p_select||l_current_char;
|
|
END IF;
|
|
--
|
|
l_position := l_position + 1;
|
|
--
|
|
WHEN l_current_char = '(' THEN
|
|
--
|
|
l_code_pos := '0130';
|
|
--
|
|
IF previous_was_token
|
|
OR previous_was_close_brace
|
|
OR previous_was_value
|
|
THEN
|
|
-- This is a problem - require an operator before the brace
|
|
-- or a previous open brace - or nothing (start of text)
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : ( - badly positioned open brace');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
l_brace_counter := l_brace_counter + 1;
|
|
--
|
|
previous_was_open_brace := TRUE;
|
|
previous_was_close_brace := FALSE;
|
|
previous_was_token := FALSE;
|
|
previous_was_operator := FALSE;
|
|
previous_was_value := FALSE;
|
|
previous_was_period := FALSE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
IF NOT p_parse_only THEN
|
|
p_select := p_select||l_current_char;
|
|
END IF;
|
|
--
|
|
l_position := l_position + 1;
|
|
--
|
|
WHEN l_current_char = ')' THEN
|
|
--
|
|
l_code_pos := '0140';
|
|
--
|
|
IF previous_was_operator
|
|
OR previous_was_open_brace
|
|
OR first_item_found
|
|
THEN
|
|
-- This is a problem - require a value or token before the brace
|
|
-- Or possibly a close brace
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : ) - badly positioned close brace');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
l_brace_counter := l_brace_counter - 1;
|
|
--
|
|
IF l_brace_counter < 0 THEN
|
|
-- This is a problem - didn't open enough braces to close this many...
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : Too many close braces');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
END IF;
|
|
--
|
|
previous_was_open_brace := FALSE;
|
|
previous_was_close_brace := TRUE;
|
|
previous_was_token := FALSE;
|
|
previous_was_operator := FALSE;
|
|
previous_was_value := FALSE;
|
|
previous_was_period := FALSE;
|
|
space_encountered := FALSE;
|
|
--
|
|
IF first_item_found THEN
|
|
first_item_found := FALSE;
|
|
END IF;
|
|
--
|
|
IF NOT p_parse_only THEN
|
|
p_select := p_select||l_current_char;
|
|
END IF;
|
|
--
|
|
l_position := l_position + 1;
|
|
--
|
|
ELSE
|
|
--
|
|
l_code_pos := '0150';
|
|
--
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : invalid character ~'||l_current_char||'~');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
EXIT rule_text_loop;
|
|
--
|
|
END CASE my_case;
|
|
--
|
|
END LOOP rule_text_loop;
|
|
--
|
|
IF l_brace_counter > 0
|
|
AND l_success
|
|
THEN
|
|
-- Didn't close all the brace pairs
|
|
caco_debug.putline('efno_rules.rule_text: Position in text: '||l_position
|
|
||' : Case : All brace pairs not closed');
|
|
l_success := FALSE;
|
|
p_select := NULL;
|
|
END IF;
|
|
--
|
|
IF l_success THEN
|
|
IF LENGTH(p_from) > 0 AND p_from NOT LIKE 'dual%' THEN
|
|
-- TRIM first comma
|
|
p_from := SUBSTR( p_from, 3 );
|
|
END IF;
|
|
IF LENGTH(p_where) > 0 THEN
|
|
-- Trim the first AND
|
|
p_where := SUBSTR( p_where, 5 );
|
|
END IF;
|
|
--
|
|
ELSIF NOT missing_nnpcv THEN
|
|
p_return_error := caco_utilities.get_module_text(2270);
|
|
-- Invalid Rule and/or Data
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
--caco_debug.putline('SP: p_select: '||p_select);
|
|
--caco_debug.putline('SP: p_from: '||p_from);
|
|
--caco_debug.putline('SP: p_where: '||p_where);
|
|
--caco_debug.putline('SP: efno_rules.rule_text END');
|
|
RETURN l_success;
|
|
--caco_debug.putline('SP: efno_rules.rule_text END');
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
caco_debug.putline('efno_rules.rule_text: Position in Code : '||l_code_pos);
|
|
caco_debug.putline('Position in TEXT : '||l_position);
|
|
caco_debug.putline(sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => 'Position in code '||l_code_pos
|
|
||' Position in TEXT : '||l_position
|
|
||' '||sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.rule_text');
|
|
--
|
|
RAISE;
|
|
END rule_text;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
FUNCTION rule_test_passed ( p_left_value IN VARCHAR2
|
|
, p_right_value IN VARCHAR2
|
|
, p_relation IN VARCHAR2 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
l_success BOOLEAN := FALSE;
|
|
l_test_sql VARCHAR2(4000);
|
|
l_test_valid VARCHAR2(5) := 'FALSE';
|
|
BEGIN
|
|
--
|
|
-- Now check to see if the values satisfy the rule_relation
|
|
--
|
|
l_test_sql := 'SELECT CASE WHEN '||p_left_value
|
|
||' '||p_relation
|
|
||' '||p_right_value
|
|
||' THEN ''TRUE'''
|
|
||' ELSE ''FALSE'''
|
|
||' END'
|
|
||' FROM dual';
|
|
--
|
|
EXECUTE IMMEDIATE l_test_sql INTO l_test_valid;
|
|
--
|
|
--caco_debug.putline(l_test_sql);
|
|
--
|
|
-- This return boolean in the nom_record will allow us to hightlight
|
|
-- specific rows to the user that are in error (done in calling program)
|
|
-- Plus that is where any related error messages will be dealt with.
|
|
--
|
|
IF l_test_valid = 'TRUE' THEN
|
|
l_success := TRUE;
|
|
ELSE
|
|
l_success := FALSE;
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END rule_test_passed;
|
|
|
|
/**
|
|
-- FUNCTION validate_rule
|
|
-- Validates a single EXISTING rule previously defined through the EFT Nominations Web interface
|
|
-- and optionally validates the data stored
|
|
--
|
|
-- Examples
|
|
-- To just parse an existing ROW rule (not assigned to a contract or contract template)
|
|
-- l_boolean := validate_rule( 12, 'ROW', TRUE, l_dummy_nnpcv_tab, l_dummy_nom_data_table );
|
|
--
|
|
-- To parse a Rule for a specified contract template
|
|
-- l_boolean := validate_rule( 12, 'ROW', TRUE, l_dummy_nnpcv_tab, l_dummy_nom_data_table, 1 );
|
|
--
|
|
-- To parse a Rule for a specified contract
|
|
-- l_boolean := validate_rule( 12, 'ROW', TRUE, l_dummy_nnpcv_tab, l_dummy_nom_data_table, p_contract_id => 2 );
|
|
-- OR l_boolean := validate_rule( 12, 'ROW', TRUE, l_dummy_nnpcv_tab, l_dummy_nom_data_table, NULL, 2 );
|
|
--
|
|
-- To parse a Rule for a contract AND validate the data for a nomination
|
|
-- l_boolean := validate_rule( 12, 'ROW', FALSE, l_nnpcv_tab, l_nom_data_table, p_contract_id => 2, p_nomination_id => 3 );
|
|
-- OR l_boolean := validate_rule( 12, 'ROW', FALSE, l_nnpcv_tab l_nom_data_table, NULL, 2, 3 );
|
|
--
|
|
-- %param p_rule_id The Unique identifier of the ROW or SHEET rule
|
|
-- %param p_rule_type ROW or SHEET
|
|
-- %param p_parse_only TRUE indicates that only syntax checking is required
|
|
-- %param p_nnpcv_tab Will return a table of CONP and COCA id's used in the rule when NOT parsing
|
|
-- %param p_nom_table Table of resulting values passed out to the calling routine for evaluation
|
|
-- %param p_template_id Unique identifier of a contract template
|
|
-- %param p_contract_id Unique identifier of a contract
|
|
-- %param p_nomination_id Unique identifier of a Nomination - used if not parsing
|
|
--
|
|
-- %return BOOLEAN TRUE indicating that the rule is valid syntactically if parse only or that the data passed the test
|
|
-- and values have been returned for further checking
|
|
*/
|
|
FUNCTION validate_rule ( p_rule_id IN NUMBER
|
|
, p_rule_type IN VARCHAR2
|
|
, p_parse_only IN BOOLEAN
|
|
, p_nnpcv_tab OUT efno_confirmations.nnpcv_tab
|
|
, p_nom_table OUT nom_validation_table
|
|
, p_template_id IN NUMBER DEFAULT 0
|
|
, p_contract_id IN NUMBER DEFAULT 0
|
|
, p_nomination_id IN NUMBER DEFAULT 0 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
--
|
|
-- Cursor to grab the parts of the row rule required
|
|
--
|
|
CURSOR c_row_rule IS
|
|
SELECT left_side
|
|
, right_side
|
|
, rule_relation
|
|
, error_message_hu
|
|
, error_message_en
|
|
FROM rules
|
|
WHERE rule_id = p_rule_id;
|
|
--
|
|
-- Cursor to grab sheet based rule information
|
|
--
|
|
CURSOR c_sheet_rule IS
|
|
SELECT left_side
|
|
, right_side
|
|
, rule_relation
|
|
, error_message_hu
|
|
, error_message_en
|
|
FROM contract_rules
|
|
WHERE coru_id = p_rule_id;
|
|
--
|
|
-- Cursor to get the date from a SHEET based nomination
|
|
-- (sheet based rules can only work against a single day nomination)
|
|
CURSOR c_sheet_nom IS
|
|
SELECT gas_day
|
|
FROM nom_net_point_cat_vals
|
|
WHERE nomi_id = p_nomination_id
|
|
AND ROWNUM = 1;
|
|
--
|
|
-- Cursor to get the specific Network Points for the given nomination
|
|
-- 8/10/2009 SP for entry mandatory offer contracts we only need to
|
|
-- select the virtual network point for row based rules
|
|
--
|
|
CURSOR c_row_nom IS
|
|
SELECT DISTINCT conp.nepo_id network_point
|
|
, nnpcv.gas_day gas_day
|
|
, conp.display_sequence display_sequence
|
|
FROM nom_net_point_cat_vals nnpcv
|
|
, cont_network_points conp
|
|
, nominations nomi
|
|
, network_points nepo
|
|
WHERE nomi.cont_id = conp.cont_id
|
|
AND nomi.nomi_id = nnpcv.nomi_id
|
|
AND nnpcv.nomi_id = p_nomination_id
|
|
--AND nomi.cont_id = p_contract_id
|
|
AND nepo.nepo_id = conp.nepo_id
|
|
AND ((efno_contracts.emo_contract(p_contract_id) = 'Y' AND nepo.nepo_type = 'V')
|
|
OR efno_contracts.emo_contract(p_contract_id) = 'N')
|
|
ORDER BY nnpcv.gas_day ASC
|
|
, conp.display_sequence ASC;
|
|
--
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
l_rule_row c_row_rule%ROWTYPE;
|
|
left_is_valid BOOLEAN := FALSE;
|
|
right_is_valid BOOLEAN := FALSE;
|
|
--
|
|
--
|
|
l_left_sql VARCHAR2(32767) := NULL;
|
|
l_left_select VARCHAR2(32767) := NULL;
|
|
l_left_from VARCHAR2(32767) := NULL;
|
|
l_left_where VARCHAR2(32767) := NULL;
|
|
--
|
|
l_right_sql VARCHAR2(32767) := NULL;
|
|
l_right_select VARCHAR2(32767) := NULL;
|
|
l_right_from VARCHAR2(32767) := NULL;
|
|
l_right_where VARCHAR2(32767) := NULL;
|
|
--
|
|
l_return_error VARCHAR2(255) := NULL;
|
|
--
|
|
l_gas_day DATE := NULL;
|
|
l_gas_day_char VARCHAR2(40) := NULL;
|
|
--
|
|
rule_found BOOLEAN := FALSE;
|
|
l_no_data BOOLEAN := FALSE;
|
|
l_nom_sites_count NUMBER := 0;
|
|
--
|
|
BEGIN
|
|
-- Get the rule information
|
|
--
|
|
IF UPPER(p_rule_type) = 'ROW' THEN
|
|
--
|
|
OPEN c_row_rule;
|
|
FETCH c_row_rule INTO l_rule_row;
|
|
IF c_row_rule%FOUND THEN
|
|
rule_found := TRUE;
|
|
END IF;
|
|
CLOSE c_row_rule;
|
|
--
|
|
ELSIF UPPER(p_rule_type) = 'SHEET' THEN
|
|
--
|
|
OPEN c_sheet_rule;
|
|
FETCH c_sheet_rule INTO l_rule_row;
|
|
IF c_sheet_rule%FOUND THEN
|
|
rule_found := TRUE;
|
|
END IF;
|
|
CLOSE c_sheet_rule;
|
|
--
|
|
END IF;
|
|
--
|
|
IF rule_found THEN
|
|
--
|
|
IF p_parse_only THEN
|
|
--
|
|
-- Process/validate the left side
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF NOT ( left_is_valid AND right_is_valid ) THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Not just parsing. We have to be checking against a nomination.
|
|
-- Need to fully evaluate the rule against the nomination data as we are not just parsing
|
|
IF p_nomination_id IS NOT NULL AND p_nomination_id > 0
|
|
AND p_contract_id IS NOT NULL AND p_contract_id > 0
|
|
THEN
|
|
--
|
|
-- Find the specific gas day if the rule is a sheet based rule
|
|
IF UPPER(p_rule_type) = 'SHEET' THEN
|
|
--
|
|
-- Process/validate the left side - output used specifically for SHEET rules
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF left_is_valid AND right_is_valid THEN
|
|
-- Ensure that the FROMs and the WHEREs are not null
|
|
IF l_left_from IS NULL THEN
|
|
l_left_from := 'dual';
|
|
END IF;
|
|
IF l_right_from IS NULL THEN
|
|
l_right_from := 'dual';
|
|
END IF;
|
|
IF l_left_where IS NOT NULL THEN
|
|
l_left_where := ' WHERE '||l_left_where;
|
|
END IF;
|
|
IF l_right_where IS NOT NULL THEN
|
|
l_right_where := ' WHERE '||l_right_where;
|
|
END IF;
|
|
--
|
|
-- We need to get the values - build the sql statements
|
|
l_left_sql := 'SELECT ('||l_left_select||') sql_value FROM '||l_left_from||l_left_where;
|
|
--
|
|
l_right_sql := 'SELECT ('||l_right_select||') sql_value FROM '||l_right_from||l_right_where;
|
|
--
|
|
OPEN c_sheet_nom;
|
|
FETCH c_sheet_nom INTO l_gas_day;
|
|
--
|
|
IF c_sheet_nom%FOUND THEN
|
|
CLOSE c_sheet_nom;
|
|
--
|
|
p_nom_table(1).nr_gas_day := l_gas_day;
|
|
p_nom_table(1).nr_rule_id := p_rule_id;
|
|
p_nom_table(1).nr_rule_type := 'SHEET';
|
|
--
|
|
-- We will have to replace any p_gas_day token with a TO_DATE conversion of the gas day
|
|
-- due to needing to submit a text SQL statement to DBMS_SQL
|
|
l_gas_day_char := 'TO_DATE('''||TO_CHAR(l_gas_day, 'DD-MON-YYYY')||''',''DD-MON-YYYY'')';
|
|
--
|
|
l_left_sql := REPLACE( l_left_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
l_right_sql := REPLACE( l_right_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
--
|
|
-- For form based rules, there should be only a single returned value from each side of the rule
|
|
--
|
|
evaluate_rule_sql( l_left_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(1).nr_left_side_value );
|
|
IF l_success THEN
|
|
-- Not worth doing this unless the left side was a success!
|
|
evaluate_rule_sql( l_right_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(1).nr_right_side_value );
|
|
END IF;
|
|
--
|
|
-- Success variable has already been set on result of evaluating each side of the SQL
|
|
-- So see if the values satisfy the relation
|
|
IF l_success THEN
|
|
--
|
|
IF rule_test_passed( p_nom_table(1).nr_left_side_value
|
|
, p_nom_table(1).nr_right_side_value
|
|
, l_rule_row.rule_relation )
|
|
THEN
|
|
p_nom_table(1).nr_valid := TRUE;
|
|
ELSE
|
|
p_nom_table(1).nr_valid := FALSE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Delete any values from the nom_table
|
|
p_nom_table.DELETE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
CLOSE c_sheet_nom;
|
|
--
|
|
-- No gas day found - not good - can't complete our work here.
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- either the left or right side of the rule is invalid
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- We need to run the rule for each and every site of the nomination...
|
|
-- So we need to construct an array of left side values and the result
|
|
-- of the comparsion with the rule relation
|
|
<<row_nom_loop>>
|
|
FOR r IN c_row_nom LOOP
|
|
-- caco_debug.putline('Validate rule: '||r.network_point);
|
|
--
|
|
l_nom_sites_count := l_nom_sites_count + 1;
|
|
left_is_valid := FALSE;
|
|
right_is_valid := FALSE;
|
|
--
|
|
l_left_sql := NULL;
|
|
l_right_sql := NULL;
|
|
--
|
|
-- Process/validate the Left side
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_net_point_id => r.network_point
|
|
, p_gas_day => r.gas_day
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_net_point_id => r.network_point
|
|
, p_gas_day => r.gas_day
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF left_is_valid AND right_is_valid THEN
|
|
--
|
|
-- Ensure that the FROMs and the WHEREs are not null
|
|
IF l_left_from IS NULL THEN
|
|
l_left_from := 'dual';
|
|
END IF;
|
|
IF l_right_from IS NULL THEN
|
|
l_right_from := 'dual';
|
|
END IF;
|
|
IF l_left_where IS NOT NULL THEN
|
|
l_left_where := ' WHERE '||l_left_where;
|
|
END IF;
|
|
IF l_right_where IS NOT NULL THEN
|
|
l_right_where := ' WHERE '||l_right_where;
|
|
END IF;
|
|
--
|
|
-- We need to get the values so lets build the sql statements
|
|
l_left_sql := 'SELECT ('||l_left_select||') sql_value FROM '||l_left_from||l_left_where;
|
|
--
|
|
l_right_sql := 'SELECT ('||l_right_select||') sql_value FROM '||l_right_from||l_right_where;
|
|
--
|
|
--
|
|
-- We will have to replace any p_gas_day token with a TO_DATE conversion of the gas day
|
|
-- due to needing to submit a text SQL statement to DBMS_SQL
|
|
l_gas_day_char := 'TO_DATE('''||TO_CHAR(r.gas_day, 'DD-MON-YYYY')||''',''DD-MON-YYYY'')';
|
|
--
|
|
l_left_sql := REPLACE( l_left_sql, 'p_gas_day', l_gas_day_char );
|
|
l_right_sql := REPLACE( l_right_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
p_nom_table(l_nom_sites_count).nr_nepo_id := r.network_point;
|
|
p_nom_table(l_nom_sites_count).nr_gas_day := r.gas_day;
|
|
p_nom_table(l_nom_sites_count).nr_rule_id := p_rule_id;
|
|
p_nom_table(l_nom_sites_count).nr_rule_type := 'ROW';
|
|
--
|
|
--
|
|
-- Get the fully evaluated Numeric Value of each side of the rule
|
|
-- for the given information and this specific network point
|
|
--
|
|
evaluate_rule_sql( l_left_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(l_nom_sites_count).nr_left_side_value );
|
|
--
|
|
IF l_success THEN
|
|
-- Not worth doing this unless the left side was a success!
|
|
evaluate_rule_sql( l_right_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(l_nom_sites_count).nr_right_side_value );
|
|
END IF;
|
|
--
|
|
IF NOT l_success THEN
|
|
-- Exit Loop as the rule won't validate...
|
|
p_nom_table.DELETE;
|
|
l_success := FALSE;
|
|
EXIT row_nom_loop;
|
|
END IF;
|
|
--
|
|
--
|
|
IF rule_test_passed( p_nom_table(l_nom_sites_count).nr_left_side_value
|
|
, p_nom_table(l_nom_sites_count).nr_right_side_value
|
|
, l_rule_row.rule_relation )
|
|
THEN
|
|
p_nom_table(l_nom_sites_count).nr_valid := TRUE;
|
|
-- caco_debug.putline('Rule is valid'||p_nom_table(l_nom_sites_count).nr_left_side_value||l_rule_row.rule_relation||p_nom_table(l_nom_sites_count).nr_right_side_value);
|
|
ELSE
|
|
p_nom_table(l_nom_sites_count).nr_valid := FALSE;
|
|
-- caco_debug.putline('Rule is invalid'||p_nom_table(l_nom_sites_count).nr_left_side_value||l_rule_row.rule_relation||p_nom_table(l_nom_sites_count).nr_right_side_value);
|
|
END IF;
|
|
--
|
|
--
|
|
ELSE
|
|
-- Exit Loop as the rule won't validate...
|
|
p_nom_table.DELETE;
|
|
l_success := FALSE;
|
|
EXIT row_nom_loop;
|
|
--
|
|
END IF;
|
|
--
|
|
END LOOP row_nom_loop;
|
|
--
|
|
IF c_row_nom%ISOPEN THEN
|
|
CLOSE c_row_nom;
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- To evaluate the rule - we need the nomination id and contract id so this fails
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
END IF; -- End of validating against a nomination
|
|
--
|
|
ELSE
|
|
-- No rule found
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END validate_rule;
|
|
|
|
FUNCTION validate_rule_conf ( p_gas_day IN DATE
|
|
, p_rule_id IN NUMBER
|
|
, p_rule_type IN VARCHAR2
|
|
, p_parse_only IN BOOLEAN
|
|
, p_nnpcv_tab IN OUT efno_confirmations.nnpcv_tab
|
|
, p_nom_table OUT nom_validation_table
|
|
, p_template_id IN NUMBER DEFAULT 0
|
|
, p_contract_id IN NUMBER DEFAULT 0
|
|
, p_nomination_id IN NUMBER DEFAULT 0 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
--
|
|
--
|
|
--
|
|
--
|
|
-- Cursor to grab the parts of the row rule required
|
|
--
|
|
CURSOR c_row_rule IS
|
|
SELECT left_side
|
|
, right_side
|
|
, rule_relation
|
|
, error_message_hu
|
|
, error_message_en
|
|
FROM rules
|
|
WHERE rule_id = p_rule_id;
|
|
--
|
|
-- Cursor to grab sheet based rule information
|
|
--
|
|
CURSOR c_sheet_rule IS
|
|
SELECT left_side
|
|
, right_side
|
|
, rule_relation
|
|
, error_message_hu
|
|
, error_message_en
|
|
FROM contract_rules
|
|
WHERE coru_id = p_rule_id;
|
|
--
|
|
-- Cursor to get the date from a SHEET based nomination
|
|
-- (sheet based rules can only work against a single day nomination)
|
|
CURSOR c_sheet_nom IS
|
|
SELECT gas_day
|
|
FROM nom_net_point_cat_vals
|
|
WHERE nomi_id = p_nomination_id
|
|
AND ROWNUM = 1;
|
|
--
|
|
-- Cursor to get the specific Network Points for the given nomination
|
|
CURSOR c_row_nom IS
|
|
SELECT DISTINCT conp.nepo_id network_point
|
|
, nnpcv.gas_day gas_day
|
|
, conp.display_sequence display_sequence
|
|
FROM nom_net_point_cat_vals nnpcv
|
|
, cont_network_points conp
|
|
, nominations nomi
|
|
WHERE nomi.cont_id = conp.cont_id
|
|
AND nomi.nomi_id = nnpcv.nomi_id
|
|
AND nnpcv.nomi_id = p_nomination_id
|
|
--AND nomi.cont_id = p_contract_id
|
|
ORDER BY nnpcv.gas_day ASC
|
|
, conp.display_sequence ASC;
|
|
--
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
l_rule_row c_row_rule%ROWTYPE;
|
|
left_is_valid BOOLEAN := FALSE;
|
|
right_is_valid BOOLEAN := FALSE;
|
|
--
|
|
--
|
|
l_left_sql VARCHAR2(32767) := NULL;
|
|
l_left_select VARCHAR2(32767) := NULL;
|
|
l_left_from VARCHAR2(32767) := NULL;
|
|
l_left_where VARCHAR2(32767) := NULL;
|
|
--
|
|
l_right_sql VARCHAR2(32767) := NULL;
|
|
l_right_select VARCHAR2(32767) := NULL;
|
|
l_right_from VARCHAR2(32767) := NULL;
|
|
l_right_where VARCHAR2(32767) := NULL;
|
|
--
|
|
l_return_error VARCHAR2(255) := NULL;
|
|
--
|
|
l_gas_day DATE := NULL;
|
|
l_gas_day_char VARCHAR2(40) := NULL;
|
|
l_int_gas_day_char VARCHAR2(40) := NULL;
|
|
--
|
|
rule_found BOOLEAN := FALSE;
|
|
l_no_data BOOLEAN := FALSE;
|
|
l_nom_sites_count NUMBER := 0;
|
|
--
|
|
FUNCTION array_invalid ( p_nepo_id IN network_points.nepo_id%TYPE ) RETURN BOOLEAN IS
|
|
l_return BOOLEAN := FALSE;
|
|
BEGIN
|
|
--
|
|
-- caco_debug.putline('Array count: '||p_nnpcv_tab.COUNT||' looking for nepo: ');
|
|
--
|
|
<<outer>>
|
|
FOR i IN 1..p_nnpcv_tab.COUNT LOOP
|
|
--
|
|
-- caco_debug.putline(i||' : conp :'||p_nnpcv_tab(i).conp_id||' nepo: '||P_NEPO_ID);
|
|
--
|
|
FOR j IN (SELECT NULL FROM cont_network_points c WHERE c.conp_id = p_nnpcv_tab(i).conp_id AND c.nepo_id = p_nepo_id) LOOP
|
|
--
|
|
-- CACO_DEBUG.PUTLINE('found!!!!!!!!!!!!!');
|
|
--
|
|
IF p_nnpcv_tab(i).in_error THEN
|
|
l_return := TRUE;
|
|
END IF;
|
|
EXIT outer;
|
|
--
|
|
END LOOP;
|
|
--
|
|
END LOOP;
|
|
--
|
|
RETURN l_return;
|
|
--
|
|
END;
|
|
--
|
|
BEGIN
|
|
-- Get the rule information
|
|
--
|
|
IF UPPER(p_rule_type) = 'ROW' THEN
|
|
--
|
|
OPEN c_row_rule;
|
|
FETCH c_row_rule INTO l_rule_row;
|
|
IF c_row_rule%FOUND THEN
|
|
rule_found := TRUE;
|
|
END IF;
|
|
CLOSE c_row_rule;
|
|
--
|
|
ELSIF UPPER(p_rule_type) = 'SHEET' THEN
|
|
--
|
|
OPEN c_sheet_rule;
|
|
FETCH c_sheet_rule INTO l_rule_row;
|
|
IF c_sheet_rule%FOUND THEN
|
|
rule_found := TRUE;
|
|
END IF;
|
|
CLOSE c_sheet_rule;
|
|
--
|
|
END IF;
|
|
--
|
|
IF rule_found THEN
|
|
--
|
|
IF p_parse_only THEN
|
|
--
|
|
-- Process/validate the left side
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF NOT ( left_is_valid AND right_is_valid ) THEN
|
|
l_success := FALSE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Not just parsing. We have to be checking against a nomination.
|
|
-- Need to fully evaluate the rule against the nomination data as we are not just parsing
|
|
IF p_nomination_id IS NOT NULL AND p_nomination_id > 0
|
|
AND p_contract_id IS NOT NULL AND p_contract_id > 0
|
|
THEN
|
|
--
|
|
-- Find the specific gas day if the rule is a sheet based rule
|
|
IF UPPER(p_rule_type) = 'SHEET' THEN
|
|
--
|
|
-- Process/validate the left side - output used specifically for SHEET rules
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF left_is_valid AND right_is_valid THEN
|
|
-- Ensure that the FROMs and the WHEREs are not null
|
|
IF l_left_from IS NULL THEN
|
|
l_left_from := 'dual';
|
|
END IF;
|
|
IF l_right_from IS NULL THEN
|
|
l_right_from := 'dual';
|
|
END IF;
|
|
IF l_left_where IS NOT NULL THEN
|
|
l_left_where := ' WHERE '||l_left_where;
|
|
END IF;
|
|
IF l_right_where IS NOT NULL THEN
|
|
l_right_where := ' WHERE '||l_right_where;
|
|
END IF;
|
|
--
|
|
-- We need to get the values - build the sql statements
|
|
l_left_sql := 'SELECT ('||l_left_select||') sql_value FROM '||l_left_from||l_left_where;
|
|
--
|
|
l_right_sql := 'SELECT ('||l_right_select||') sql_value FROM '||l_right_from||l_right_where;
|
|
--
|
|
OPEN c_sheet_nom;
|
|
FETCH c_sheet_nom INTO l_gas_day;
|
|
--
|
|
IF c_sheet_nom%FOUND THEN
|
|
CLOSE c_sheet_nom;
|
|
--
|
|
p_nom_table(1).nr_gas_day := l_gas_day;
|
|
p_nom_table(1).nr_rule_id := p_rule_id;
|
|
p_nom_table(1).nr_rule_type := 'SHEET';
|
|
--
|
|
-- We will have to replace any p_gas_day token with a TO_DATE conversion of the gas day
|
|
-- due to needing to submit a text SQL statement to DBMS_SQL
|
|
l_gas_day_char := 'TO_DATE('''||TO_CHAR(l_gas_day, 'DD-MON-YYYY')||''',''DD-MON-YYYY'')';
|
|
--
|
|
l_left_sql := REPLACE( l_left_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
l_right_sql := REPLACE( l_right_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
--
|
|
-- For form based rules, there should be only a single returned value from each side of the rule
|
|
--
|
|
evaluate_rule_sql( l_left_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(1).nr_left_side_value );
|
|
IF l_success THEN
|
|
-- Not worth doing this unless the left side was a success!
|
|
evaluate_rule_sql( l_right_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(1).nr_right_side_value );
|
|
END IF;
|
|
--
|
|
-- Success variable has already been set on result of evaluating each side of the SQL
|
|
-- So see if the values satisfy the relation
|
|
IF l_success THEN
|
|
--
|
|
IF rule_test_passed( p_nom_table(1).nr_left_side_value
|
|
, p_nom_table(1).nr_right_side_value
|
|
, l_rule_row.rule_relation )
|
|
THEN
|
|
p_nom_table(1).nr_valid := TRUE;
|
|
ELSE
|
|
p_nom_table(1).nr_valid := FALSE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Delete any values from the nom_table
|
|
p_nom_table.DELETE;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
CLOSE c_sheet_nom;
|
|
--
|
|
-- No gas day found - not good - can't complete our work here.
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- either the left or right side of the rule is invalid
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- We need to run the rule for each and every site of the nomination...
|
|
-- So we need to construct an array of left side values and the result
|
|
-- of the comparsion with the rule relation
|
|
<<row_nom_loop>>
|
|
FOR r IN c_row_nom LOOP
|
|
--
|
|
-- caco_debug.putline('efno_rules.nom row nepo is:'||r.network_point);
|
|
IF array_invalid(r.network_point) THEN
|
|
-- caco_debug.putline('Network point: '||r.network_point||' invalid.');
|
|
--
|
|
l_nom_sites_count := l_nom_sites_count + 1;
|
|
left_is_valid := FALSE;
|
|
right_is_valid := FALSE;
|
|
--
|
|
l_left_sql := NULL;
|
|
l_right_sql := NULL;
|
|
--
|
|
-- Process/validate the Left side
|
|
left_is_valid := rule_text( p_text => l_rule_row.left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_left_select
|
|
, p_from => l_left_from
|
|
, p_where => l_left_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_net_point_id => r.network_point
|
|
, p_gas_day => r.gas_day
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
-- Process/validate the Right side
|
|
right_is_valid := rule_text( p_text => l_rule_row.right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_right_select
|
|
, p_from => l_right_from
|
|
, p_where => l_right_where
|
|
, p_nnpcv_tab => p_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_nomination_id => p_nomination_id
|
|
, p_net_point_id => r.network_point
|
|
, p_gas_day => r.gas_day
|
|
, p_parse_only => p_parse_only
|
|
, p_return_error => l_return_error );
|
|
--
|
|
IF left_is_valid AND right_is_valid THEN
|
|
--
|
|
-- Ensure that the FROMs and the WHEREs are not null
|
|
IF l_left_from IS NULL THEN
|
|
l_left_from := 'dual';
|
|
END IF;
|
|
IF l_right_from IS NULL THEN
|
|
l_right_from := 'dual';
|
|
END IF;
|
|
IF l_left_where IS NOT NULL THEN
|
|
l_left_where := ' WHERE '||l_left_where;
|
|
END IF;
|
|
IF l_right_where IS NOT NULL THEN
|
|
l_right_where := ' WHERE '||l_right_where;
|
|
END IF;
|
|
--
|
|
-- We need to get the values so lets build the sql statements
|
|
l_left_sql := 'SELECT ('||l_left_select||') sql_value FROM '||l_left_from||l_left_where;
|
|
--
|
|
l_right_sql := 'SELECT ('||l_right_select||') sql_value FROM '||l_right_from||l_right_where;
|
|
--
|
|
--
|
|
-- We will have to replace any p_gas_day token with a TO_DATE conversion of the gas day
|
|
-- due to needing to submit a text SQL statement to DBMS_SQL
|
|
-- l_gas_day_char := 'TO_DATE('''||TO_CHAR(r.gas_day, 'DD-MON-YYYY')||''',''DD-MON-YYYY'')';
|
|
l_gas_day_char := 'TO_DATE('''||TO_CHAR(p_gas_day, 'DD-MON-YYYY')||''',''DD-MON-YYYY'')';
|
|
caco_debug.putline('l_gas_day_char: '||l_gas_day_char);
|
|
--
|
|
l_left_sql := REPLACE( l_left_sql, 'p_gas_day', l_gas_day_char );
|
|
l_right_sql := REPLACE( l_right_sql, 'p_gas_day', l_gas_day_char );
|
|
--
|
|
--caco_debug.putline(l_right_sql);
|
|
--
|
|
p_nom_table(l_nom_sites_count).nr_nepo_id := r.network_point;
|
|
p_nom_table(l_nom_sites_count).nr_gas_day := r.gas_day;
|
|
p_nom_table(l_nom_sites_count).nr_rule_id := p_rule_id;
|
|
p_nom_table(l_nom_sites_count).nr_rule_type := 'ROW';
|
|
--
|
|
--
|
|
-- Get the fully evaluated Numeric Value of each side of the rule
|
|
-- for the given information and this specific network point
|
|
--
|
|
evaluate_rule_sql( l_left_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(l_nom_sites_count).nr_left_side_value );
|
|
--
|
|
IF l_success THEN
|
|
-- Not worth doing this unless the left side was a success!
|
|
evaluate_rule_sql( l_right_sql
|
|
, l_success
|
|
, l_no_data
|
|
, p_nom_table(l_nom_sites_count).nr_right_side_value );
|
|
END IF;
|
|
--
|
|
IF NOT l_success THEN
|
|
-- Exit Loop as the rule won't validate...
|
|
p_nom_table.DELETE;
|
|
l_success := FALSE;
|
|
EXIT row_nom_loop;
|
|
END IF;
|
|
--
|
|
--
|
|
caco_debug.putline('EVAL: '||p_nom_table(l_nom_sites_count).nr_left_side_value||l_rule_row.rule_relation||p_nom_table(l_nom_sites_count).nr_right_side_value);
|
|
IF rule_test_passed( p_nom_table(l_nom_sites_count).nr_left_side_value
|
|
, p_nom_table(l_nom_sites_count).nr_right_side_value
|
|
, l_rule_row.rule_relation )
|
|
THEN
|
|
p_nom_table(l_nom_sites_count).nr_valid := TRUE;
|
|
ELSE
|
|
p_nom_table(l_nom_sites_count).nr_valid := FALSE;
|
|
END IF;
|
|
--
|
|
--
|
|
ELSE
|
|
-- Exit Loop as the rule won't validate...
|
|
p_nom_table.DELETE;
|
|
l_success := FALSE;
|
|
EXIT row_nom_loop;
|
|
--
|
|
END IF;
|
|
--
|
|
END IF; -- if network point invalid
|
|
--
|
|
END LOOP row_nom_loop;
|
|
--
|
|
IF c_row_nom%ISOPEN THEN
|
|
CLOSE c_row_nom;
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- To evaluate the rule - we need the nomination id and contract id so this fails
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
END IF; -- End of validating against a nomination
|
|
--
|
|
ELSE
|
|
-- No rule found
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END validate_rule_conf;
|
|
|
|
|
|
FUNCTION insert_row_rule( p_rule_id OUT NUMBER
|
|
, p_rule_name IN VARCHAR2
|
|
, p_left_side IN VARCHAR2
|
|
, p_rule_relation IN VARCHAR2
|
|
, p_right_side IN VARCHAR2
|
|
, p_err_message_hu IN VARCHAR2
|
|
, p_err_message_en IN VARCHAR2
|
|
, p_return_error OUT VARCHAR2 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
l_success BOOLEAN := TRUE;
|
|
BEGIN
|
|
--
|
|
BEGIN
|
|
INSERT INTO rules
|
|
( rule_id
|
|
, rule_name
|
|
, left_side
|
|
, rule_relation
|
|
, right_side
|
|
, error_message_hu
|
|
, error_message_en )
|
|
VALUES
|
|
( rule_seq.nextval
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en )
|
|
RETURNING rule_id INTO p_rule_id;
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Return message
|
|
p_return_error := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.insert_row_rule');
|
|
--
|
|
END;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END insert_row_rule;
|
|
|
|
|
|
|
|
|
|
FUNCTION update_row_rule( p_rule_id IN NUMBER
|
|
, p_rule_name IN VARCHAR2
|
|
, p_left_side IN VARCHAR2
|
|
, p_rule_relation IN VARCHAR2
|
|
, p_right_side IN VARCHAR2
|
|
, p_err_message_hu IN VARCHAR2
|
|
, p_err_message_en IN VARCHAR2
|
|
, p_return_error OUT VARCHAR2 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
l_success BOOLEAN := TRUE;
|
|
BEGIN
|
|
--
|
|
BEGIN
|
|
UPDATE rules
|
|
SET rule_name = p_rule_name
|
|
, left_side = p_left_side
|
|
, rule_relation = p_rule_relation
|
|
, right_side = p_right_side
|
|
, error_message_hu = p_err_message_hu
|
|
, error_message_en = p_err_message_en
|
|
WHERE rule_id = p_rule_id;
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Return message
|
|
p_return_error := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.update_row_rule');
|
|
--
|
|
END;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END update_row_rule;
|
|
|
|
|
|
|
|
PROCEDURE upd_cotr_seq( p_template_id IN NUMBER
|
|
, p_cotr_id IN NUMBER
|
|
, p_sequence IN VARCHAR2 )
|
|
IS
|
|
--
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
BEGIN
|
|
UPDATE contract_template_rules
|
|
SET display_sequence = p_sequence
|
|
WHERE cotr_id = p_cotr_id;
|
|
EXCEPTION
|
|
WHEN invalid_number THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2335);
|
|
-- Invalid Number entered. Please try again.
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2338);
|
|
-- Unable to update sequence number. Please contact support
|
|
caco_debug.putline('efno_rules.upd_cotr_seq : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.upd_cotr_seq');
|
|
--
|
|
END;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow092$.template_rules( p_template_id => p_template_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSE
|
|
--
|
|
efnow092$.template_rules( p_template_id => p_template_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END upd_cotr_seq;
|
|
|
|
|
|
|
|
PROCEDURE delete_template_rule( p_template_id IN NUMBER
|
|
, p_cotr_id IN NUMBER )
|
|
IS
|
|
-- Cursor to list all contracts with the given template
|
|
CURSOR c_contracts IS
|
|
SELECT cont_id
|
|
FROM contracts
|
|
WHERE cote_id = p_template_id;
|
|
--
|
|
CURSOR c_cotr_rule IS
|
|
SELECT rule_id
|
|
FROM contract_template_rules
|
|
WHERE cotr_id = p_cotr_id;
|
|
--
|
|
l_rule_id contract_template_rules.rule_id%TYPE;
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
SAVEPOINT before_del_cotr;
|
|
--
|
|
OPEN c_cotr_rule;
|
|
FETCH c_cotr_rule INTO l_rule_id;
|
|
CLOSE c_cotr_rule;
|
|
--
|
|
-- Delete the rule from all contracts with the template
|
|
<<contract_loop>>
|
|
FOR r IN c_contracts LOOP
|
|
--
|
|
BEGIN
|
|
DELETE contract_rules
|
|
WHERE NVL(rule_id,0) = l_rule_id
|
|
AND cont_id = r.cont_id
|
|
AND NVL(inherited,'N') = 'Y';
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2251);
|
|
-- Deleting template rule from existing contracts failed. Please contact support
|
|
caco_debug.putline('efno_rules.delete_template_rule : Error deleting rule from contracts: '
|
|
||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.delete_template_rule');
|
|
--
|
|
EXIT contract_loop;
|
|
END;
|
|
--
|
|
END LOOP contract_loop;
|
|
--
|
|
-- Delete rule from the template
|
|
IF l_success THEN
|
|
BEGIN
|
|
DELETE contract_template_rules
|
|
WHERE cotr_id = p_cotr_id
|
|
AND cote_id = p_template_id;
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2250);
|
|
-- Deleting contract template rule failed. Please contact support
|
|
caco_debug.putline('efno_rules.delete_template_rule : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.delete_template_rule');
|
|
--
|
|
END;
|
|
END IF;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow050$.template_rules( p_template_id => p_template_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSE
|
|
ROLLBACK TO SAVEPOINT before_del_cotr;
|
|
--
|
|
efnow050$.template_rules( p_template_id => p_template_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END delete_template_rule;
|
|
|
|
|
|
FUNCTION add_cote_rule_to_cont( p_template_id IN NUMBER
|
|
, p_rule_id IN NUMBER
|
|
, p_display_sequence IN NUMBER
|
|
, p_return_error OUT VARCHAR2 )
|
|
RETURN BOOLEAN
|
|
IS
|
|
-- Cursor to list all contracts with the given template
|
|
CURSOR c_contracts IS
|
|
SELECT cont_id
|
|
FROM contracts
|
|
WHERE cote_id = p_template_id;
|
|
--
|
|
-- Cursor to see if the rule already exists for a contract with this template
|
|
CURSOR c_coru_exists( cp_cont_id IN NUMBER
|
|
, cp_rule_id IN NUMBER )
|
|
IS
|
|
SELECT coru_id
|
|
FROM contract_rules
|
|
WHERE cont_id = cp_cont_id
|
|
AND rule_id = cp_rule_id;
|
|
--
|
|
l_coru_id contract_rules.coru_id%TYPE := 0;
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
SAVEPOINT before_add_to_cont;
|
|
--
|
|
IF NVL(p_rule_id,-1) != -1 THEN
|
|
<<contracts_loop>>
|
|
FOR r IN c_contracts LOOP
|
|
--
|
|
OPEN c_coru_exists( r.cont_id, p_rule_id );
|
|
FETCH c_coru_exists INTO l_coru_id;
|
|
IF c_coru_exists%FOUND THEN
|
|
CLOSE c_coru_exists;
|
|
-- Already have this rule - so make it inherited
|
|
BEGIN
|
|
UPDATE contract_rules
|
|
SET inherited = 'Y'
|
|
WHERE coru_id = l_coru_id;
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
p_return_error := caco_utilities.get_module_text(2333);
|
|
-- Failed to insert rule. Please contact support
|
|
caco_debug.putline('efno_rules.add_cote_rule_to_cont : Error updating existing contract rule: '
|
|
||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.add_cote_rule_to_cont');
|
|
--
|
|
END;
|
|
ELSE
|
|
CLOSE c_coru_exists;
|
|
-- Need to insert this one
|
|
BEGIN
|
|
INSERT INTO contract_rules
|
|
( coru_id
|
|
, display_sequence
|
|
, inherited
|
|
, cont_id
|
|
, coru_type
|
|
, rule_id )
|
|
VALUES
|
|
( coru_seq.NEXTVAL
|
|
, NVL(p_display_sequence,10)
|
|
, 'Y'
|
|
, r.cont_id
|
|
, 'ROW'
|
|
, p_rule_id );
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
p_return_error := caco_utilities.get_module_text(2333);
|
|
-- Failed to insert rule. Please contact support
|
|
caco_debug.putline('efno_rules.add_cote_rule_to_cont : Error inserting rule for existing contract : '
|
|
||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.add_cote_rule_to_cont');
|
|
--
|
|
END;
|
|
END IF;
|
|
--
|
|
END LOOP contracts_loop;
|
|
END IF;
|
|
--
|
|
IF NOT l_success THEN
|
|
ROLLBACK TO SAVEPOINT before_add_to_cont;
|
|
END IF;
|
|
--
|
|
RETURN l_success;
|
|
--
|
|
END add_cote_rule_to_cont;
|
|
|
|
|
|
|
|
|
|
PROCEDURE add_template_rule( p_template_id IN NUMBER
|
|
, p_rule_id IN NUMBER )
|
|
IS
|
|
--
|
|
-- Cursor for checking if rule already exists for this contract template
|
|
CURSOR c_rule IS
|
|
SELECT 'X'
|
|
FROM contract_template_rules
|
|
WHERE cote_id = p_template_id
|
|
AND NVL(rule_id,0) = p_rule_id;
|
|
--
|
|
l_dummy VARCHAR2(1) := 'X';
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_valid_rule BOOLEAN := TRUE;
|
|
--
|
|
l_dummy_nnpcv_tab efno_confirmations.nnpcv_tab;
|
|
l_dummy_nom_data_table nom_validation_table;
|
|
l_display_sequence contract_template_rules.display_sequence%TYPE := 0;
|
|
--
|
|
l_success BOOLEAN := TRUE;
|
|
l_duplicate_submission BOOLEAN := FALSE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
SAVEPOINT before_ins_cotr;
|
|
--
|
|
l_dummy_nom_data_table := g_empty_nom_val_table;
|
|
--
|
|
-- First, test if this contract has the correct parameters to add this rule
|
|
--
|
|
l_valid_rule := validate_rule( p_rule_id => p_rule_id
|
|
, p_rule_type => 'ROW'
|
|
, p_parse_only => TRUE
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_nom_table => l_dummy_nom_data_table
|
|
, p_template_id => p_template_id );
|
|
--
|
|
IF l_valid_rule THEN
|
|
--
|
|
-- Check to ensure that we dont already have this rule...
|
|
-- Could happen if user presses back on the browser screen and refreshes
|
|
OPEN c_rule;
|
|
FETCH c_rule INTO l_dummy;
|
|
IF c_rule%FOUND THEN
|
|
l_success := FALSE;
|
|
l_duplicate_submission := TRUE;
|
|
END IF;
|
|
CLOSE c_rule;
|
|
--
|
|
IF NOT l_duplicate_submission THEN
|
|
--
|
|
BEGIN
|
|
INSERT INTO contract_template_rules
|
|
( cotr_id
|
|
, display_sequence
|
|
, cote_id
|
|
, rule_id )
|
|
VALUES
|
|
( cotr_seq.NEXTVAL
|
|
, ( SELECT NVL(MAX(cotr2.display_sequence),0)+10
|
|
FROM contract_template_rules cotr2
|
|
WHERE cotr2.cote_id = p_template_id )
|
|
, p_template_id
|
|
, p_rule_id )
|
|
RETURNING display_sequence INTO l_display_sequence;
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2333);
|
|
-- Failed to insert rule. Please contact support
|
|
caco_debug.putline('efno_rules.add_template_rule : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.add_template_rule');
|
|
--
|
|
END;
|
|
--
|
|
-- Now we can try to add this rule to every contract with this template
|
|
IF l_success THEN
|
|
--
|
|
l_success := add_cote_rule_to_cont( p_template_id
|
|
, p_rule_id
|
|
, l_display_sequence
|
|
, l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END IF; -- Not duplicate submission
|
|
--
|
|
ELSE
|
|
--
|
|
l_err_message := caco_utilities.get_module_text(2297);
|
|
-- Selected Rule is not valid for this contract template.
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow050$.template_rules( p_template_id => p_template_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSIF l_duplicate_submission THEN
|
|
--
|
|
ROLLBACK TO SAVEPOINT before_ins_cotr;
|
|
--
|
|
efnow050$.template_rules( p_template_id => p_template_id );
|
|
--
|
|
ELSE
|
|
--
|
|
ROLLBACK TO SAVEPOINT before_ins_cotr;
|
|
--
|
|
efnow050$.template_rules( p_template_id => p_template_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END add_template_rule;
|
|
|
|
|
|
|
|
PROCEDURE upd_coru_seq( p_contract_id IN NUMBER
|
|
, p_coru_id IN NUMBER
|
|
, p_sequence IN VARCHAR2 )
|
|
IS
|
|
--
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
BEGIN
|
|
UPDATE contract_rules
|
|
SET display_sequence = p_sequence
|
|
WHERE coru_id = p_coru_id;
|
|
EXCEPTION
|
|
WHEN invalid_number THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2335);
|
|
-- Invalid Number entered. Please try again.
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2338);
|
|
-- Unable to update sequence number. Please contact support
|
|
caco_debug.putline('efno_rules.upd_coru_seq : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.upd_coru_seq');
|
|
--
|
|
END;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow092$.contract_rules( p_contract_id => p_contract_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSE
|
|
--
|
|
efnow092$.contract_rules( p_contract_id => p_contract_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END upd_coru_seq;
|
|
|
|
|
|
|
|
PROCEDURE delete_contract_rule( p_contract_id IN NUMBER
|
|
, p_coru_id IN NUMBER )
|
|
IS
|
|
--
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_success BOOLEAN := TRUE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
BEGIN
|
|
DELETE contract_rules
|
|
WHERE coru_id = p_coru_id
|
|
AND cont_id = p_contract_id;
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2249);
|
|
-- Deleting contract rule failed. Please contact support
|
|
caco_debug.putline('efno_rules.delete_contract_rule : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.delete_contract_rule');
|
|
--
|
|
END;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow050$.contract_rules( p_contract_id => p_contract_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSE
|
|
--
|
|
efnow050$.contract_rules( p_contract_id => p_contract_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END delete_contract_rule;
|
|
|
|
|
|
PROCEDURE add_contract_row_rule( p_contract_id IN NUMBER
|
|
, p_rule_id IN NUMBER )
|
|
IS
|
|
-- Cursor for checking if rule already exists.
|
|
CURSOR c_rule IS
|
|
SELECT 'X'
|
|
FROM contract_rules
|
|
WHERE cont_id = p_contract_id
|
|
AND NVL(rule_id,0) = p_rule_id;
|
|
--
|
|
l_dummy VARCHAR2(1) := 'X';
|
|
l_err_message VARCHAR2(255) := NULL;
|
|
l_valid_rule BOOLEAN := TRUE;
|
|
l_dummy_nnpcv_tab efno_confirmations.nnpcv_tab;
|
|
l_dummy_nom_data_table nom_validation_table;
|
|
l_success BOOLEAN := TRUE;
|
|
l_duplicate_submission BOOLEAN := FALSE;
|
|
--
|
|
BEGIN
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow092$ - in turn called from screen efnow050$
|
|
IF NOT caco_security.security_check('efnow050$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
l_dummy_nom_data_table := g_empty_nom_val_table;
|
|
--
|
|
-- First, test if this contract has the correct parameters to add this rule
|
|
--
|
|
l_valid_rule := validate_rule( p_rule_id => p_rule_id
|
|
, p_rule_type => 'ROW'
|
|
, p_parse_only => TRUE
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_nom_table => l_dummy_nom_data_table
|
|
, p_contract_id => p_contract_id );
|
|
--
|
|
IF l_valid_rule THEN
|
|
--
|
|
-- Check to ensure that we dont already have this rule...
|
|
-- Could happen if user presses back on the browser screen and refreshes
|
|
OPEN c_rule;
|
|
FETCH c_rule INTO l_dummy;
|
|
IF c_rule%FOUND THEN
|
|
l_success := FALSE;
|
|
l_duplicate_submission := TRUE;
|
|
END IF;
|
|
CLOSE c_rule;
|
|
--
|
|
IF NOT l_duplicate_submission THEN
|
|
BEGIN
|
|
INSERT INTO contract_rules
|
|
( coru_id
|
|
, display_sequence
|
|
, inherited
|
|
, cont_id
|
|
, coru_type
|
|
, rule_id )
|
|
VALUES
|
|
( coru_seq.NEXTVAL
|
|
, ( SELECT NVL(MAX(coru2.display_sequence),0)+10
|
|
FROM contract_rules coru2
|
|
WHERE coru2.cont_id = p_contract_id )
|
|
, 'N'
|
|
, p_contract_id
|
|
, 'ROW'
|
|
, p_rule_id );
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
l_err_message := caco_utilities.get_module_text(2333);
|
|
-- Failed to insert rule. Please contact support
|
|
caco_debug.putline('efno_rules.add_contract_row_rule : Error : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.add_contract_row_rule');
|
|
--
|
|
END;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
l_err_message := caco_utilities.get_module_text(2298);
|
|
-- Selected Rule is not valid for this contract.
|
|
l_success := FALSE;
|
|
--
|
|
END IF;
|
|
--
|
|
IF l_success THEN
|
|
--
|
|
COMMIT;
|
|
efnow050$.contract_rules( p_contract_id => p_contract_id
|
|
, p_success => 'Y' );
|
|
--
|
|
ELSIF l_duplicate_submission THEN
|
|
--
|
|
efnow050$.contract_rules( p_contract_id => p_contract_id );
|
|
--
|
|
ELSE
|
|
--
|
|
efnow050$.contract_rules( p_contract_id => p_contract_id
|
|
, p_error => 'Y'
|
|
, p_err_msg => l_err_message );
|
|
--
|
|
END IF;
|
|
--
|
|
END add_contract_row_rule;
|
|
|
|
|
|
|
|
/**
|
|
-- PROCEDURE insert_or_update_rule
|
|
-- As it says on the tin
|
|
-- validates the data stored passed and then inserts new rule or updates existing one
|
|
--
|
|
-- %param p_ins_or_upd INSERT or UPDATE
|
|
-- %param p_template_id Unique Identifier of a Contract Template
|
|
-- %param p_contract_id Unique Identifier of a Contract
|
|
-- %param p_rule_type Rule type - ROW or SHEET
|
|
-- %param p_coru_id Unique identifier of the SHEET based rule (optional)
|
|
-- %param p_rule_id Unique identifier of the ROW based rule (optional)
|
|
-- %param p_rule_name Descriptive name of the rule
|
|
-- %param p_left_side The text of the rule to the left hand side of the relation
|
|
-- %param p_right_side The text of the rule to the right hand side of the relation
|
|
-- %param p_rule_relation <, <=, >, >=, =, !=
|
|
-- %param p_err_message_hu Error message to display if values fail this rule
|
|
-- %param p_err_message_en Error message in English
|
|
*/
|
|
PROCEDURE insert_or_update_rule( p_ins_or_upd IN VARCHAR2 DEFAULT NULL
|
|
, p_template_id IN NUMBER DEFAULT NULL
|
|
, p_contract_id IN NUMBER DEFAULT NULL
|
|
, p_coru_id IN NUMBER DEFAULT NULL
|
|
, p_rule_id IN NUMBER DEFAULT NULL
|
|
, p_rule_name IN VARCHAR2 DEFAULT NULL
|
|
, p_rule_type IN VARCHAR2 DEFAULT NULL
|
|
, p_err_message_hu IN VARCHAR2 DEFAULT NULL
|
|
, p_err_message_en IN VARCHAR2 DEFAULT NULL
|
|
, p_left_side IN VARCHAR2 DEFAULT NULL
|
|
, p_rule_relation IN VARCHAR2 DEFAULT NULL
|
|
, p_right_side IN VARCHAR2 DEFAULT NULL )
|
|
IS
|
|
--
|
|
CURSOR c_rule_name( cp_name IN VARCHAR2
|
|
, cp_rule IN NUMBER
|
|
, cp_coru IN NUMBER )
|
|
IS
|
|
SELECT 'X'
|
|
FROM rules
|
|
WHERE UPPER(rule_name) = UPPER(cp_name)
|
|
AND rule_id != cp_rule
|
|
UNION ALL
|
|
SELECT 'X'
|
|
FROM contract_rules
|
|
WHERE NVL(UPPER(rule_name),'&^%"?(') = UPPER(cp_name)
|
|
AND coru_id != cp_coru;
|
|
--
|
|
l_new_rule_id NUMBER := NULL;
|
|
l_new_coru_id NUMBER := NULL;
|
|
--
|
|
l_error_message VARCHAR2(250) := NULL;
|
|
l_display_sequence contract_rules.display_sequence%TYPE;
|
|
--
|
|
l_dummy_char VARCHAR2(1);
|
|
l_dummy_select VARCHAR2(1);
|
|
l_dummy_from VARCHAR2(1);
|
|
l_dummy_where VARCHAR2(1);
|
|
l_dummy_nnpcv_tab efno_confirmations.nnpcv_tab;
|
|
l_return_error VARCHAR2(255) := NULL;
|
|
--
|
|
left_side_valid BOOLEAN := FALSE;
|
|
right_side_valid BOOLEAN := FALSE;
|
|
--
|
|
p_item_name_array owa_util.vc_arr;
|
|
p_item_value_array owa_util.vc_arr;
|
|
--
|
|
l_success BOOLEAN := TRUE; -- Used to track how well we are doing in this code..
|
|
--
|
|
BEGIN
|
|
caco_debug.putline('SP: efno_rules.insert_or_update_rule START');
|
|
-- Check we have permission to be using this module.
|
|
-- Only called from efnow093$ - in turn called from screen efnow080$
|
|
IF NOT caco_security.security_check('efnow080$') THEN
|
|
RETURN;
|
|
END IF;
|
|
--
|
|
-- Check that the correct information has been passed from the screen
|
|
-- Pop up a warning message if details have not been received / are invalid
|
|
-- Remember to make this multilingual....
|
|
--
|
|
IF p_rule_name IS NULL
|
|
OR LENGTH(p_rule_name) > 50
|
|
THEN
|
|
-- Need a rule name - and one within the column limits
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup message to alert User to error
|
|
l_error_message := caco_utilities.get_module_text(2208);
|
|
-- A valid Rule Name is required. Maximum length 50 characters
|
|
--
|
|
ELSIF ( p_err_message_hu IS NULL
|
|
OR LENGTH(p_err_message_hu) > 250 )
|
|
THEN
|
|
--
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup message to alert User to error
|
|
l_error_message := caco_utilities.get_module_text(2263);
|
|
-- Hungarian error message must be present with a maximum length of 250 characters
|
|
--
|
|
ELSIF p_err_message_en IS NULL
|
|
OR LENGTH(p_err_message_en) > 250
|
|
THEN
|
|
--
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup message to alert User to error
|
|
l_error_message := caco_utilities.get_module_text(2256);
|
|
-- English error message must be present with a maximum length of 250 characters
|
|
--
|
|
ELSIF p_left_side IS NULL
|
|
OR LENGTH(p_left_side) > 4000
|
|
THEN
|
|
--
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup message to alert User to error
|
|
l_error_message := caco_utilities.get_module_text(2305);
|
|
-- The left side of the rule must be present with a maximum length of 4000 characters
|
|
--
|
|
ELSIF p_right_side IS NULL
|
|
OR LENGTH(p_right_side) > 4000
|
|
THEN
|
|
--
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup message to alert User to error
|
|
l_error_message := caco_utilities.get_module_text(2306);
|
|
-- The right side of the rule must be present with a maximum length of 4000 characters
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
IF l_success THEN
|
|
-- Check that the rule name is not a duplicate (exclude current rule for update)
|
|
--
|
|
OPEN c_rule_name( p_rule_name
|
|
, NVL(p_rule_id,0)
|
|
, NVL(p_coru_id,0) );
|
|
FETCH c_rule_name INTO l_dummy_char;
|
|
IF c_rule_name%FOUND THEN
|
|
-- Rule name already used. Cant have a duplicate
|
|
l_success := FALSE;
|
|
--
|
|
-- Return Error message - Duplicate RULE_NAME
|
|
l_error_message := caco_utilities.get_module_text(2254);
|
|
-- Duplicate Rule Name encountered. Please change the Rule Name and retry
|
|
END IF;
|
|
CLOSE c_rule_name;
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
IF l_success THEN
|
|
-- Soldier on to validate the given rule
|
|
IF ( p_template_id IS NULL OR p_template_id = 0 )
|
|
AND ( p_contract_id IS NULL OR p_contract_id = 0 )
|
|
THEN
|
|
-- Standalone rule - MUST be a ROW type rule
|
|
IF p_rule_type = 'ROW' THEN
|
|
--
|
|
left_side_valid := rule_text( p_text => p_left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
right_side_valid := rule_text( p_text => p_right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
ELSE
|
|
-- Not valid to have a SHEET based rule that isn't attached to a contract
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup error message - "Invalid Rule Type specified"
|
|
l_error_message := caco_utilities.get_module_text(2269);
|
|
-- Invalid Rule Type specified. Valid values are ROW and SHEET
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF p_template_id IS NOT NULL
|
|
AND p_template_id > 0
|
|
AND ( p_contract_id IS NULL OR p_contract_id = 0 )
|
|
THEN
|
|
-- Template based rule - must also be a ROW type rule
|
|
IF p_rule_type = 'ROW' THEN
|
|
--
|
|
left_side_valid := rule_text( p_text => p_left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
right_side_valid := rule_text( p_text => p_right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_template_id => p_template_id
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
ELSE
|
|
-- Not valid to have a SHEET based rule that isn't attached to a contract
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup error message - "Invalid Rule Type specified"
|
|
l_error_message := caco_utilities.get_module_text(2268);
|
|
-- Invalid Rule Type specified. Valid value is ROW
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF p_contract_id IS NOT NULL
|
|
AND p_contract_id > 0
|
|
AND ( p_template_id IS NULL OR p_template_id = 0 )
|
|
THEN
|
|
-- Contract based rule
|
|
--
|
|
caco_debug.putline('SP: efno_rules.insert_or_update_rule 010');
|
|
left_side_valid := rule_text( p_text => p_left_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
caco_debug.putline('SP: efno_rules.insert_or_update_rule 020');
|
|
right_side_valid := rule_text( p_text => p_right_side
|
|
, p_rule_type => p_rule_type
|
|
, p_select => l_dummy_select
|
|
, p_from => l_dummy_from
|
|
, p_where => l_dummy_where
|
|
, p_nnpcv_tab => l_dummy_nnpcv_tab
|
|
, p_contract_id => p_contract_id
|
|
, p_parse_only => TRUE
|
|
, p_return_error => l_return_error );
|
|
--
|
|
END IF;
|
|
--
|
|
--
|
|
IF l_success THEN
|
|
-- Check that the left and right sides validated correctly
|
|
--
|
|
IF left_side_valid AND right_side_valid THEN
|
|
--
|
|
-- Need to insert or update
|
|
-- Deal with the most complicated first - contract rules
|
|
IF p_contract_id IS NOT NULL
|
|
AND p_contract_id > 0
|
|
THEN
|
|
-- Check the rule type
|
|
IF p_rule_type = 'SHEET' THEN
|
|
--
|
|
IF p_ins_or_upd = 'INSERT' THEN
|
|
--
|
|
-- Just Insert the data into CONTRACT_RULES
|
|
BEGIN
|
|
INSERT INTO contract_rules
|
|
( coru_id
|
|
, display_sequence
|
|
, inherited
|
|
, cont_id
|
|
, coru_type
|
|
, rule_name
|
|
, left_side
|
|
, rule_relation
|
|
, right_side
|
|
, error_message_hu
|
|
, error_message_en )
|
|
VALUES
|
|
( coru_seq.nextval
|
|
, ( SELECT NVL(MAX(r2.display_sequence),0) + 10
|
|
FROM contract_rules r2
|
|
WHERE r2.cont_id = p_contract_id )
|
|
, 'N'
|
|
, p_contract_id
|
|
, 'SHEET'
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en )
|
|
RETURNING coru_id INTO l_new_coru_id;
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup Error message
|
|
l_error_message := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.insert_or_update_rule');
|
|
--
|
|
END;
|
|
ELSE
|
|
-- Update SHEET rule
|
|
BEGIN
|
|
UPDATE contract_rules
|
|
SET rule_name = p_rule_name
|
|
, left_side = p_left_side
|
|
, rule_relation = p_rule_relation
|
|
, right_side = p_right_side
|
|
, error_message_hu = p_err_message_hu
|
|
, error_message_en = p_err_message_en
|
|
WHERE coru_id = p_coru_id;
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup Error message
|
|
l_error_message := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
caco_debug.putline('efno_rules.insert_or_update_rule : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.insert_or_update_rule');
|
|
--
|
|
END;
|
|
--
|
|
END IF; -- Insert or update SHEET
|
|
--
|
|
ELSE
|
|
-- ROW rule
|
|
--
|
|
IF p_ins_or_upd = 'INSERT' THEN
|
|
--
|
|
l_success := insert_row_rule( l_new_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
IF l_success THEN
|
|
-- Just Insert the data into CONTRACT_RULES
|
|
BEGIN
|
|
INSERT INTO contract_rules
|
|
( coru_id
|
|
, display_sequence
|
|
, inherited
|
|
, cont_id
|
|
, coru_type
|
|
, rule_id )
|
|
VALUES
|
|
( coru_seq.nextval
|
|
, ( SELECT NVL(MAX(r2.display_sequence),0) + 10
|
|
FROM contract_rules r2
|
|
WHERE r2.cont_id = p_contract_id )
|
|
, 'N'
|
|
, p_contract_id
|
|
, 'ROW'
|
|
, l_new_rule_id );
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup Error message
|
|
l_error_message := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
caco_debug.putline('efno_rules.insert_or_update_rule : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.insert_or_update_rule');
|
|
--
|
|
END;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Update contract ROW rule
|
|
l_success := update_row_rule( p_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
END IF; -- Insert or update ROW contract rule
|
|
--
|
|
END IF;
|
|
--
|
|
-- Now build the Rule screen URL as a query with the appropriate created values
|
|
IF l_success THEN
|
|
--
|
|
p_item_name_array(2) := 'P_CATEGORY';
|
|
p_item_value_array(2) := 'CONTRACT';
|
|
p_item_name_array(3) := 'P_CONTRACT_ID';
|
|
p_item_value_array(3) := p_contract_id;
|
|
--
|
|
IF p_rule_type = 'SHEET' THEN
|
|
p_item_name_array(4) := 'P_CORU_ID';
|
|
p_item_value_array(4) := NVL(l_new_coru_id, p_coru_id);
|
|
ELSE
|
|
p_item_name_array(4) := 'P_RULE_ID';
|
|
p_item_value_array(4) := NVL(l_new_rule_id, p_rule_id);
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF p_template_id IS NOT NULL
|
|
AND p_template_id > 0
|
|
THEN
|
|
--
|
|
IF p_ins_or_upd = 'INSERT' THEN
|
|
--
|
|
-- First INSERT the data into the RULES table returning the new RULE_ID
|
|
-- New ROW rule for a specific template
|
|
l_success := insert_row_rule( l_new_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
IF l_success THEN
|
|
-- Insert a link record into CONTRACT_TEMPLATE_RULES
|
|
BEGIN
|
|
INSERT INTO contract_template_rules
|
|
( cotr_id
|
|
, display_sequence
|
|
, cote_id
|
|
, rule_id )
|
|
VALUES
|
|
( cotr_seq.nextval
|
|
, ( SELECT NVL(MAX(t2.display_sequence),0) + 10
|
|
FROM contract_template_rules t2
|
|
WHERE t2.cote_id = p_template_id )
|
|
, p_template_id
|
|
, l_new_rule_id )
|
|
RETURNING display_sequence INTO l_display_sequence;
|
|
--
|
|
EXCEPTION
|
|
WHEN others THEN
|
|
l_success := FALSE;
|
|
--
|
|
-- Popup Error message
|
|
l_error_message := caco_utilities.get_module_text(2330);
|
|
-- An unexpected error has occurred. Please contact support
|
|
caco_debug.putline('efno_rules.insert_or_update_rule : '||sqlerrm(sqlcode));
|
|
-- Write an error and carry on
|
|
cout_err.report_and_go( p_exception_number => sqlcode
|
|
, p_exception_message => sqlerrm(sqlcode)
|
|
, p_source => 'efno_rules.insert_or_update_rule');
|
|
--
|
|
END;
|
|
END IF;
|
|
--
|
|
ELSE
|
|
-- Update Template ROW rule
|
|
l_success := update_row_rule( p_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
END IF; -- Insert or Update Template Rule
|
|
--
|
|
-- Now build the Rule screen URL as a query with the appropriate created values
|
|
IF l_success THEN
|
|
--
|
|
p_item_name_array(2) := 'P_CATEGORY';
|
|
p_item_value_array(2) := 'TEMPLATE';
|
|
p_item_name_array(3) := 'P_TEMPLATE_ID';
|
|
p_item_value_array(3) := p_template_id;
|
|
p_item_name_array(4) := 'P_RULE_ID';
|
|
p_item_value_array(4) := NVL(l_new_rule_id, p_rule_id);
|
|
--
|
|
END IF;
|
|
--
|
|
ELSE
|
|
--
|
|
IF p_ins_or_upd = 'INSERT' THEN
|
|
--
|
|
-- New ROW rule not attached to a contract or a template
|
|
l_success := insert_row_rule( l_new_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
ELSE
|
|
-- Update standalone ROW rule
|
|
l_success := update_row_rule( p_rule_id
|
|
, p_rule_name
|
|
, p_left_side
|
|
, p_rule_relation
|
|
, p_right_side
|
|
, p_err_message_hu
|
|
, p_err_message_en
|
|
, l_error_message );
|
|
--
|
|
END IF; -- Insert or Update standalone Rule
|
|
--
|
|
-- Now build the Rule screen URL as a query with the appropriate created values
|
|
IF l_success THEN
|
|
--
|
|
p_item_name_array(2) := 'P_RULE_ID';
|
|
p_item_value_array(2) := NVL(l_new_rule_id, p_rule_id);
|
|
--
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
ELSIF left_side_valid THEN
|
|
--
|
|
-- Right side is invalid - Popup error message
|
|
--
|
|
l_success := FALSE;
|
|
l_error_message := caco_utilities.get_module_text(2296);
|
|
-- Rule right side is invalid
|
|
--
|
|
ELSIF right_side_valid THEN
|
|
--
|
|
-- Left side is invalid - Popup error message
|
|
--
|
|
l_success := FALSE;
|
|
l_error_message := caco_utilities.get_module_text(2295);
|
|
-- Rule left side is invalid
|
|
--
|
|
ELSE
|
|
--
|
|
-- both sides invalid - Popup error message
|
|
--
|
|
l_success := FALSE;
|
|
l_error_message := caco_utilities.get_module_text(2226);
|
|
-- Both sides of the rule are invalid
|
|
--
|
|
END IF;
|
|
--
|
|
END IF;
|
|
--
|
|
END IF; -- IF l_success
|
|
--
|
|
IF l_success
|
|
AND p_template_id IS NOT NULL
|
|
AND p_template_id > 0
|
|
THEN
|
|
-- need to add the rule to all the associated contracts too.
|
|
l_success := add_cote_rule_to_cont( p_template_id
|
|
, l_new_rule_id
|
|
, l_display_sequence
|
|
, l_error_message );
|
|
END IF;
|
|
--
|
|
-- If all is still well, call the RULE screen with the values
|
|
IF l_success THEN
|
|
-- Set the success message as the first item
|
|
p_item_name_array(1) := 'P_SUCCESS';
|
|
p_item_value_array(1) := 'Y';
|
|
--
|
|
efnow080$.rule_startup( p_item_name_array
|
|
, p_item_value_array );
|
|
--
|
|
ELSE
|
|
-- Clear the name/value pair arrays
|
|
p_item_name_array.DELETE;
|
|
p_item_value_array.DELETE;
|
|
--
|
|
-- Send back the originally submitted values and the appropriate warning message
|
|
--
|
|
p_item_name_array(1) := 'P_ERROR';
|
|
p_item_value_array(1) := 'Y';
|
|
p_item_name_array(2) := 'P_ERR_MSG';
|
|
p_item_value_array(2) := l_error_message;
|
|
p_item_name_array(3) := 'P_INS_OR_UPD';
|
|
p_item_value_array(3) := p_ins_or_upd;
|
|
p_item_name_array(4) := 'P_TEMPLATE_ID';
|
|
p_item_value_array(4) := p_template_id;
|
|
p_item_name_array(5) := 'P_CONTRACT_ID';
|
|
p_item_value_array(5) := p_contract_id;
|
|
p_item_name_array(6) := 'P_CORU_ID';
|
|
p_item_value_array(6) := p_coru_id;
|
|
p_item_name_array(7) := 'P_RULE_ID';
|
|
p_item_value_array(7) := p_rule_id;
|
|
p_item_name_array(8) := 'P_RULE_NAME';
|
|
p_item_value_array(8) := p_rule_name;
|
|
p_item_name_array(9) := 'P_RULE_TYPE';
|
|
p_item_value_array(9) := p_rule_type;
|
|
p_item_name_array(10) := 'P_ERR_MESSAGE_HU';
|
|
p_item_value_array(10) := p_err_message_hu;
|
|
p_item_name_array(11) := 'P_ERR_MESSAGE_EN';
|
|
p_item_value_array(11) := p_err_message_en;
|
|
p_item_name_array(12) := 'P_LEFT_SIDE';
|
|
p_item_value_array(12) := p_left_side;
|
|
p_item_name_array(13) := 'P_RULE_RELATION';
|
|
p_item_value_array(13) := p_rule_relation;
|
|
p_item_name_array(14) := 'P_RIGHT_SIDE';
|
|
p_item_value_array(14) := p_right_side;
|
|
--
|
|
efnow080$.rule_startup( p_item_name_array
|
|
, p_item_value_array );
|
|
--
|
|
END IF;
|
|
--
|
|
END insert_or_update_rule;
|
|
|
|
FUNCTION get_nepg_value(p_nomi_id IN NUMBER,
|
|
p_nepg_id IN NUMBER,
|
|
p_coca_id IN NUMBER,
|
|
p_conf_id IN NUMBER,
|
|
p_gas_day IN nom_net_point_cat_vals.gas_day%TYPE)
|
|
RETURN NUMBER IS
|
|
--
|
|
CURSOR cu_nepg_nnpcv IS
|
|
SELECT NVL(SUM(nnpcv.value),0)
|
|
FROM nominations nomi,
|
|
nom_net_point_cat_vals nnpcv,
|
|
cont_network_points conp,
|
|
contract_categories coca,
|
|
network_point_groups nepg,
|
|
network_point_mappings nepm
|
|
WHERE nomi.nomi_id = p_nomi_id
|
|
AND nomi.nomi_id = nnpcv.nomi_id
|
|
AND coca.coca_id = p_coca_id
|
|
AND nepg.nepg_id = p_nepg_id
|
|
AND nepg.nepg_id = nepm.nepg_id
|
|
AND nepm.nepo_id = conp.nepo_id
|
|
AND nnpcv.coca_id = coca.coca_id
|
|
AND nnpcv.conp_id = conp.conp_id
|
|
AND nnpcv.gas_day = p_gas_day;
|
|
--
|
|
CURSOR cu_nepg_cnpcv IS
|
|
SELECT NVL(SUM(cnpcv.value),0)
|
|
FROM conf_net_point_cat_vals cnpcv,
|
|
network_point_groups nepg,
|
|
network_point_mappings nepm,
|
|
cont_network_points conp
|
|
WHERE cnpcv.conf_id = p_conf_id
|
|
AND (cnpcv.nomi_id = p_nomi_id OR p_nomi_id = 0)
|
|
AND cnpcv.coca_id = p_coca_id
|
|
AND nepg.nepg_id = p_nepg_id
|
|
AND nepg.nepg_id = nepm.nepg_id
|
|
AND nepm.nepo_id = conp.nepo_id
|
|
AND cnpcv.conp_id = conp.conp_id
|
|
AND cnpcv.gas_day = p_gas_day;
|
|
--
|
|
l_value NUMBER := 0;
|
|
--
|
|
BEGIN
|
|
--
|
|
IF p_conf_id = 0 THEN
|
|
--caco_debug.putline('get_nepg_value 010: cu_nepg_nnpcv');
|
|
OPEN cu_nepg_nnpcv;
|
|
FETCH cu_nepg_nnpcv INTO l_value;
|
|
CLOSE cu_nepg_nnpcv;
|
|
ELSE
|
|
--caco_debug.putline('get_nepg_value 020: cu_nepg_cnpcv');
|
|
OPEN cu_nepg_cnpcv;
|
|
FETCH cu_nepg_cnpcv INTO l_value;
|
|
CLOSE cu_nepg_cnpcv;
|
|
END IF;
|
|
--
|
|
RETURN l_value;
|
|
--
|
|
END;
|
|
|
|
FUNCTION get_npgp_value(p_cont_id IN NUMBER,
|
|
p_nepg_id IN NUMBER)
|
|
RETURN NUMBER IS
|
|
--
|
|
CURSOR cu_npgp IS
|
|
SELECT NVL(npgp.value,0)
|
|
FROM network_point_gp_params npgp
|
|
WHERE npgp.cont_id = p_cont_id
|
|
AND npgp.nepg_id = p_nepg_id;
|
|
--
|
|
l_value NUMBER := 0;
|
|
--
|
|
BEGIN
|
|
--
|
|
OPEN cu_npgp;
|
|
FETCH cu_npgp INTO l_value;
|
|
CLOSE cu_npgp;
|
|
--
|
|
RETURN l_value;
|
|
--
|
|
END;
|
|
|
|
/**
|
|
-- 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
|
|
-- Package intitialisation
|
|
NULL;
|
|
END efno_rules;
|
|
/
|