CREATE OR REPLACE PACKAGE BODY efno_nominations IS -- /** -- PROCEDURE upd_nomi_timestamp -- Autonomous Transaction -- Updates the nomination timestamp with the given date -- Used by the timestamping functions when a RETRY has been required -- -- %param p_nomi_id Unique Identifier of the nomination to be updated -- %param p_timestamp Successful timestamp information -- */ PROCEDURE upd_nomi_timestamp(p_nomi_id IN nominations.nomi_id%TYPE, p_timestamp IN DATE) IS -- PRAGMA AUTONOMOUS_TRANSACTION; -- BEGIN -- BEGIN -- UPDATE confirmations c SET c.confirmation_sent = p_timestamp WHERE c.nomi_id = p_nomi_id AND c.confirmation_type = 'NO' ; -- COMMIT; -- EXCEPTION WHEN others THEN NULL; END; -- END upd_nomi_timestamp; -- FUNCTION get_coca ( p_coca_id IN contract_categories.coca_id%TYPE , p_column IN VARCHAR2 ) RETURN VARCHAR IS -- l_return VARCHAR2(1000) := NULL; -- BEGIN -- FOR i IN ( SELECT coca.* ,cate.code AS cate_code ,cate.name AS cate_name ,cate.interuptible AS cate_int ,cate.units AS cate_units FROM contract_categories coca ,categories cate WHERE coca.coca_id = p_coca_id AND cate.cate_id = coca.cate_id ) LOOP -- IF p_column = 'DISPLAY_SEQUENCE' THEN -- l_return := i.display_sequence; -- END IF; -- IF p_column = 'CATE_NAME' THEN -- l_return := i.cate_name; -- END IF; -- IF p_column = 'CATE_UNITS' THEN -- l_return := i.cate_units; -- END IF; -- EXIT; -- END LOOP; -- RETURN l_return; -- END get_coca; FUNCTION get_conp ( p_conp_id cont_network_points.conp_id%TYPE , p_column IN VARCHAR2 ) RETURN VARCHAR IS -- l_return VARCHAR2(1000) := NULL; -- BEGIN -- FOR i IN ( SELECT conp.* FROM cont_network_points conp WHERE conp.conp_id = p_conp_id ) LOOP -- IF p_column = 'DISPLAY_SEQUENCE' THEN -- l_return := i.display_sequence; -- END IF; -- EXIT; -- END LOOP; -- RETURN l_return; -- END get_conp; -- FUNCTION get_conp ( p_nepo_id IN network_points.nepo_id%TYPE , p_cont_id IN contracts.cont_id%TYPE ) RETURN cont_network_points.conp_id%TYPE IS -- l_return cont_network_points.conp_id%TYPE; -- BEGIN -- BEGIN SELECT conp.conp_id INTO l_return FROM cont_network_points conp WHERE conp.nepo_id = p_nepo_id AND conp.cont_id = p_cont_id; EXCEPTION WHEN OTHERS THEN l_return := NULL; END; -- RETURN l_return; -- END get_conp; -- /** -- FUNCTION evaluate_rule -- Validates a single EXISTING rule previously defined through the EFT Nominations Web interface -- and validates the data stored returning the coca and conp ids of the items checked in the rule -- (also works out if any conp/coca combinations are missing but shouldnt be a problem here...) -- -- %param p_rule_id The Unique identifier of the ROW (rule_id) or SHEET (coru_id) rule -- %param p_rule_type ROW or SHEET -- %param p_nnpcv_tab OUT Table of conp and coca id's that this rule checks -- %param p_contract_id Unique identifier of a contract -- %param p_nomination_id Unique identifier of a Nomination -- -- %return BOOLEAN TRUE indicating that the rule is valid syntactically and the data passed the test -- FALSE indicates that processing is required to show those elements in error */ FUNCTION evaluate_rule ( p_rule_id IN rules.rule_id%TYPE , p_rule_type IN VARCHAR2 , p_nnpcv_tab OUT efno_confirmations.nnpcv_tab , p_contract_id IN contracts.cont_id%TYPE DEFAULT 0 , p_nomination_id IN nominations.nomi_id%TYPE DEFAULT 0 , p_return_error OUT VARCHAR2 ) 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 -- 5/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_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_left_side_value NUMBER := 0; l_left_error VARCHAR2(255) := 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_right_side_value NUMBER := 0; l_right_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; invalid_row_rules BOOLEAN := FALSE; -- l_element_count NUMBER := 0; -- 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; -- -- Get the specific gas day for the SHEET rule OPEN c_sheet_nom; FETCH c_sheet_nom INTO l_gas_day; -- IF c_sheet_nom%NOTFOUND THEN l_success := FALSE; p_return_error := 'Invalid Nomination - Gas Day not found. Please contact support'; END IF; CLOSE c_sheet_nom; -- END IF; -- IF rule_found AND l_success THEN -- -- 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 -- ROW rules will evaluate the rule per network point - this just proves validity for ROW rules left_is_valid := efno_rules.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_return_error => l_left_error ); -- -- Process/validate the Right side right_is_valid := efno_rules.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_return_error => l_right_error ); -- IF l_left_error IS NOT NULL THEN p_return_error := l_left_error; ELSIF l_right_error IS NOT NULL THEN p_return_error := l_right_error; END IF; -- IF left_is_valid AND right_is_valid AND p_return_error IS NULL 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; -- -- 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 ); -- -- There should be only a single returned value from each side of the rule efno_rules.evaluate_rule_sql( l_left_sql , l_success , l_no_data , l_left_side_value ); -- IF l_success THEN caco_debug.putline('its all good'); -- Not worth doing this unless the left side was a success! efno_rules.evaluate_rule_sql( l_right_sql , l_success , l_no_data , l_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 NOT efno_rules.rule_test_passed( l_left_side_value , l_right_side_value , l_rule_row.rule_relation ) THEN l_success := FALSE; END IF; -- END IF; -- ELSE -- Either the left side or the right side of the rule is invalid - how much should we report? -- If p_return_error is NULL then we have missing nnpcv records (contract changed) -- Need to check for this in the calling package. -- -- Set the gas day in the nnpcv_tab for sheet nominations -- (Row rules automatically have to do this) IF NVL(p_nnpcv_tab.COUNT,0) > 0 THEN FOR i IN 1..p_nnpcv_tab.COUNT LOOP p_nnpcv_tab(i).gas_day := l_gas_day; END LOOP; END IF; -- 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 <> FOR r IN c_row_nom LOOP -- l_rule_success := TRUE; l_nom_sites_count := l_nom_sites_count + 1; left_is_valid := FALSE; right_is_valid := FALSE; -- l_no_data := FALSE; l_left_sql := NULL; l_right_sql := NULL; l_left_error := NULL; l_right_error := NULL; -- l_element_count := NVL(p_nnpcv_tab.COUNT, 0); -- left_is_valid := efno_rules.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_return_error => l_left_error ); -- -- Process/validate the Right side right_is_valid := efno_rules.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_return_error => l_right_error ); -- IF l_left_error IS NOT NULL THEN p_return_error := l_left_error; ELSIF l_right_error IS NOT NULL THEN p_return_error := l_right_error; END IF; -- IF left_is_valid AND right_is_valid AND p_return_error IS NULL 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 ); -- -- Get the fully evaluated Numeric Value of each side of the rule -- for the given information and this specific network point efno_rules.evaluate_rule_sql( l_left_sql , l_rule_success , l_no_data , l_left_side_value ); -- IF l_rule_success THEN -- Not worth doing this unless the left side was a success! efno_rules.evaluate_rule_sql( l_right_sql , l_rule_success , l_no_data , l_right_side_value ); END IF; -- IF NOT efno_rules.rule_test_passed( l_left_side_value , l_right_side_value , l_rule_row.rule_relation ) THEN -- l_success := FALSE; -- FOR i IN l_element_count+1..p_nnpcv_tab.COUNT LOOP -- p_nnpcv_tab(i-1).in_error := TRUE; p_nnpcv_tab(i-1).conp_id := get_conp( p_nepo_id => r.network_point , p_cont_id => p_contract_id ); -- END LOOP; -- END IF; -- -- ELSIF p_return_error IS NULL THEN -- Dont want to Exit Loop even though the rule won't validate... -- we need to check for every network point before failing invalid_row_rules := TRUE; -- ELSE -- Exit the loop - something went wrong that we havent dealt with 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; -- ELSIF NOT rule_found THEN -- No rule found l_success := FALSE; -- END IF; -- IF invalid_row_rules THEN l_success := FALSE; END IF; -- RETURN l_success; -- END evaluate_rule; -- -- -- FUNCTION rule_loops( p_nomi_id IN nominations.nomi_id%TYPE , p_contract_id IN contracts.cont_id%TYPE , p_return_error OUT VARCHAR2 , p_nnpcv_tab OUT efno_confirmations.nnpcv_tab ) RETURN BOOLEAN IS -- CURSOR c_rowrule_err( cp_rule_id IN NUMBER ) IS SELECT error_message_en , error_message_hu FROM rules WHERE rule_id = cp_rule_id; -- CURSOR c_sheetrule_err( cp_coru_id IN NUMBER ) IS SELECT error_message_en , error_message_hu FROM contract_rules WHERE coru_id = cp_coru_id; -- l_rule_record efno_contracts.contract_rules_rec; l_temp_rule rules.rule_id%TYPE; l_nnpcv_tab efno_confirmations.nnpcv_tab; l_rule_errm_en rules.error_message_en%TYPE; l_rule_errm_hu rules.error_message_hu%TYPE; rule_valid BOOLEAN := TRUE; nom_invalid BOOLEAN := FALSE; missing_nnpcv BOOLEAN := FALSE; -- l_success BOOLEAN := TRUE; -- l_count_rules NUMBER := 0; -- BEGIN -- -- Need to loop through the contract rules and validate the nomination -- OPEN efno_contracts.c_rules( p_contract_id ); FETCH efno_contracts.c_rules INTO l_rule_record; -- <> WHILE efno_contracts.c_rules%FOUND LOOP -- l_count_rules := l_count_rules + 1; l_temp_rule := 0; l_nnpcv_tab.DELETE; l_rule_errm_en := NULL; l_rule_errm_hu := NULL; -- IF l_rule_record.rule_type = 'SHEET' THEN l_temp_rule := l_rule_record.coru_id; ELSE l_temp_rule := l_rule_record.rule_id; END IF; -- rule_valid := evaluate_rule( l_temp_rule , l_rule_record.rule_type , l_nnpcv_tab , p_contract_id , p_nomi_id , p_return_error ); -- IF NOT rule_valid AND p_return_error IS NULL THEN -- flag each of the coca/conp pairings in the table as invalid -- Also grab the rule error message dependent on current system language IF l_rule_record.rule_type = 'SHEET' THEN -- OPEN c_sheetrule_err(l_rule_record.coru_id); FETCH c_sheetrule_err INTO l_rule_errm_en, l_rule_errm_hu; CLOSE c_sheetrule_err; -- ELSE -- OPEN c_rowrule_err(l_rule_record.rule_id); FETCH c_rowrule_err INTO l_rule_errm_en, l_rule_errm_hu; CLOSE c_rowrule_err; -- END IF; -- nom_invalid := TRUE; -- IF caco_utilities.get_syus_lang = 'HU' THEN p_return_error := l_rule_errm_hu; ELSE p_return_error := l_rule_errm_en; END IF; -- p_nnpcv_tab := l_nnpcv_tab; -- ELSIF NOT rule_valid AND p_return_error IS NOT NULL THEN -- Something more fundamental is wrong -- Should we abandon the attempt? nom_invalid := TRUE; -- EXIT contract_rules_loop; -- END IF; -- -- Exit the loop if invalid -- IF nom_invalid THEN EXIT; END IF; -- -- Fetch the next rule record -- FETCH efno_contracts.c_rules INTO l_rule_record; -- END LOOP contract_rules_loop; -- CLOSE efno_contracts.c_rules; -- RETURN nom_invalid; -- END rule_loops; -- /** -- FUNCTION about -- -- Returns the version number and VSS header for this package -- -- %return The version number and VSS header for this package */ FUNCTION about RETURN VARCHAR2 IS BEGIN RETURN(g_revision || CHR(10) || g_header); END about; -- -- BEGIN -- Initialization NULL; -- END efno_nominations; /