CREATE OR REPLACE PACKAGE BODY caco_utilities IS g_header CONSTANT VARCHAR2(160) := '$Header: /Isle Of Grain/database/PLSQL/caco_utilities.pck 1 7/01/05 12:54 Gilberta $'; g_revision CONSTANT VARCHAR2(160) := '$Revision: 1 $'; /* * $History: caco_utilities.pck $ * * ***************** Version 1 ***************** * User: Gilberta Date: 7/01/05 Time: 12:54 * Created in $/Isle Of Grain/database/PLSQL * Initial Version * * -- Based on CALMS revision 11 -- */ -- -- Constants for the hash functions -- c_hash_base CONSTANT NUMBER := 0; c_hash_size CONSTANT NUMBER := POWER(2 ,30); -- -- Log Error -- PROCEDURE log_error(p_error_rec IN error_logs%ROWTYPE) IS PRAGMA AUTONOMOUS_TRANSACTION; BEGIN -- INSERT INTO error_logs (error_type ,SOURCE ,severity ,ERROR_CODE ,error_message ,error_date ,error_status) VALUES (p_error_rec.error_type ,p_error_rec.SOURCE ,p_error_rec.severity ,p_error_rec.ERROR_CODE ,p_error_rec.error_message ,p_error_rec.error_date ,p_error_rec.error_status); -- COMMIT; -- EXCEPTION WHEN OTHERS THEN raise_application_error(-20000 ,caco_utilities.get_system_name || ' ' || SQLERRM ,TRUE); ROLLBACK; END log_error; -- -- Record Field -- -- Created as a varchar returning function as should work for all file elements allowing data conversion later. -- p_string is the entire comma delimited to be used and p_field_number is the field element to be returned. -- FUNCTION record_field(p_string IN VARCHAR2 ,p_delimiter IN VARCHAR2 ,p_field_number IN NUMBER) RETURN VARCHAR2 IS v_field_value VARCHAR2(2000); -- c_start_position CONSTANT NUMBER := 1; -- BEGIN -- v_field_value := NULL; -- IF p_field_number > 1 AND instr(p_string ,p_delimiter ,c_start_position ,p_field_number) > 0 THEN v_field_value := substr(p_string ,instr(p_string ,p_delimiter ,c_start_position ,p_field_number - 1) + 1 ,instr(p_string ,p_delimiter ,c_start_position ,p_field_number) - (instr(p_string ,p_delimiter ,c_start_position ,p_field_number - 1) + 1)); ELSIF p_field_number > 1 AND instr(p_string ,p_delimiter ,c_start_position ,p_field_number) = 0 THEN -- -- Need to handle final field diffently as no delimiter at end of record. -- v_field_value := substr(p_string ,instr(p_string ,p_delimiter ,c_start_position ,p_field_number - 1) + 1 ,length(p_string) - instr(p_string ,p_delimiter ,c_start_position ,p_field_number - 1) + 1); ELSE -- -- Need to handle field 1 differently as no delimiter at start of record. -- IF nvl(instr(p_string ,p_delimiter ,c_start_position ,p_field_number) - 1 ,0) > 0 THEN v_field_value := substr(p_string ,c_start_position ,instr(p_string ,p_delimiter ,c_start_position ,p_field_number) - 1); ELSE -- No delimiter. v_field_value := substr(p_string ,c_start_position ,length(p_string)); END IF; END IF; -- RETURN(v_field_value); -- END record_field; -- -- Delimiter to table -- FUNCTION delimiter_to_table(p_string IN VARCHAR2 ,p_delimiter IN VARCHAR2 ,p_error_msg OUT VARCHAR2) RETURN t_vc_table IS v_num_of_fields NUMBER; tbl_empty t_vc_table; tbl_of_values t_vc_table; BEGIN -- tbl_of_values := tbl_empty; v_num_of_fields := 0; -- -- Need to add one to this value as there is always one more field than delimeters -- v_num_of_fields := (length(p_string) - length(REPLACE(p_string ,p_delimiter))) + 1; FOR v_position IN 1 .. v_num_of_fields LOOP -- tbl_of_values(v_position) := record_field(p_string => p_string ,p_delimiter => p_delimiter ,p_field_number => v_position); -- END LOOP; -- RETURN(tbl_of_values); -- EXCEPTION WHEN OTHERS THEN p_error_msg := 'Error in delimiter_to_table : ' || SQLERRM; END delimiter_to_table; -- -- -- Disassemble file name -- PROCEDURE disassemble_file_name(p_file_name IN VARCHAR2 ,p_file_prefix OUT VARCHAR2 ,p_date_created OUT VARCHAR2 ,p_file_suffix OUT VARCHAR2 ,p_error_msg OUT VARCHAR2) IS l_string VARCHAR2(255); l_file_prefix VARCHAR2(10); l_date_created VARCHAR2(20); l_file_suffix VARCHAR2(10); c_file_prefix_length CONSTANT NUMBER := 4; c_file_delimiter CONSTANT VARCHAR(1) := '.'; c_suffix_length CONSTANT NUMBER := 3; BEGIN l_string := NULL; l_file_prefix := NULL; l_date_created := NULL; l_file_suffix := NULL; -- -- Get the file suffix (1st piece) and remove it. -- l_string := p_file_name; l_file_prefix := substr(l_string ,1 ,c_file_prefix_length); l_string := substr(l_string ,c_file_prefix_length + 1); -- -- Get the serial Number (2nd piece and remove it). -- l_date_created := substr(l_string ,1 ,instr(l_string ,c_file_delimiter) - 1); l_string := substr(l_string ,instr(l_string ,c_file_delimiter) + 1); -- -- Final piece should just be the date and suffix of the file name, we need the last two characters of the suffix -- which should be the stream number. -- l_file_suffix := substr(l_string ,-c_suffix_length ,c_suffix_length); -- -- Assign the out parameters. -- p_file_prefix := l_file_prefix; p_date_created := l_date_created; p_file_suffix := l_file_suffix; -- EXCEPTION WHEN OTHERS THEN p_error_msg := 'ERROR in disassemble_file_name : ' || SQLERRM; END disassemble_file_name; -- PROCEDURE get_user_data(p_reload IN BOOLEAN DEFAULT FALSE) IS -- -- BEGIN -- IF caco_security.g_current_syus_id IS NULL OR caco_security.g_current_cust_id IS NULL OR caco_security.g_current_inte_id IS NULL OR caco_security.g_client_id IS NULL OR p_reload THEN -- caco_security.get_session_data; -- END IF; -- END get_user_data; FUNCTION get_system_customer RETURN NUMBER IS BEGIN -- RETURN cout_system_configuration.get_configuration_item('CUST_ID'); -- END get_system_customer; -- FUNCTION get_system_intermediary RETURN NUMBER IS BEGIN -- RETURN cout_system_configuration.get_configuration_item('INTE_ID'); -- END get_system_intermediary; -- FUNCTION get_system_name RETURN VARCHAR2 IS BEGIN -- RETURN nvl(cout_system_configuration.get_configuration_item('NAME') ,'No Name'); -- END get_system_name; -- FUNCTION get_sypr_name(p_sypr_id IN system_profiles.sypr_id%TYPE ,p_default IN VARCHAR2 DEFAULT 'No Profile Name') RETURN system_profiles.NAME%TYPE IS -- v_return VARCHAR2(100); -- BEGIN -- FOR v_sypr IN (SELECT NAME FROM system_profiles WHERE sypr_id = p_sypr_id) LOOP v_return := v_sypr.NAME; END LOOP; -- RETURN nvl(v_return ,p_default); -- END get_sypr_name; FUNCTION get_syus_id RETURN system_users.syus_id%TYPE IS -- -- BEGIN -- get_user_data; -- RETURN nvl(caco_security.g_current_syus_id ,get_system_user); -- EXCEPTION WHEN OTHERS THEN RETURN get_system_user; END get_syus_id; -- FUNCTION get_cust_id RETURN customers.cust_id%TYPE IS -- -- BEGIN -- get_user_data; -- RETURN caco_security.g_current_cust_id; -- END get_cust_id; FUNCTION get_system_user RETURN NUMBER IS BEGIN -- RETURN cout_system_configuration.get_configuration_item('SYUS_ID'); -- END get_system_user; -- -- FUNCTION get_inte_id RETURN intermediaries.inte_id%TYPE IS -- -- BEGIN -- get_user_data; -- RETURN caco_security.g_current_inte_id; -- END get_inte_id; -- FUNCTION get_syus_name(p_syus_id IN system_users.syus_id%TYPE DEFAULT NULL) RETURN system_users.db_username%TYPE IS -- CURSOR cur_syus(p_syus_id IN system_users.syus_id%TYPE) IS SELECT syus.db_username FROM system_users syus WHERE syus.syus_id = p_syus_id; -- v_return system_users.db_username%TYPE; v_syus_id system_users.syus_id%TYPE; -- BEGIN -- IF p_syus_id IS NOT NULL THEN -- v_syus_id := p_syus_id; -- ELSE -- v_syus_id := get_syus_id; -- END IF; -- OPEN cur_syus(v_syus_id); FETCH cur_syus INTO v_return; CLOSE cur_syus; -- RETURN nvl(v_return ,'No User Name'); -- END get_syus_name; -- FUNCTION get_syus_lang(p_syus_id IN system_users.syus_id%TYPE DEFAULT NULL) RETURN system_users.LANGUAGE%TYPE IS -- CURSOR cur_syus(p_syus_id IN system_users.syus_id%TYPE) IS SELECT syus.LANGUAGE FROM system_users syus WHERE syus.syus_id = p_syus_id; -- v_return system_users.LANGUAGE%TYPE; v_syus_id system_users.syus_id%TYPE; -- BEGIN -- IF p_syus_id IS NOT NULL THEN -- v_syus_id := p_syus_id; -- ELSE -- v_syus_id := get_syus_id; -- END IF; -- OPEN cur_syus(v_syus_id); FETCH cur_syus INTO v_return; CLOSE cur_syus; -- RETURN(v_return); -- END get_syus_lang; -- FUNCTION get_cust_name(p_cust_id IN customers.cust_id%TYPE DEFAULT NULL ,p_default IN VARCHAR2 DEFAULT 'No Customer Name') RETURN customers.NAME%TYPE IS -- v_return customers.NAME%TYPE; v_cust_id customers.cust_id%TYPE; -- BEGIN -- IF p_cust_id IS NULL THEN -- v_cust_id := get_cust_id; -- ELSE -- v_cust_id := p_cust_id; -- END IF; -- FOR v_cust IN (SELECT NAME FROM customers WHERE cust_id = v_cust_id) LOOP v_return := v_cust.NAME; END LOOP; -- RETURN nvl(v_return ,p_default); -- END get_cust_name; -- FUNCTION get_inte_name(p_inte_id IN intermediaries.inte_id%TYPE DEFAULT NULL ,p_default IN VARCHAR2 DEFAULT 'No Intermediary Name') RETURN intermediaries.NAME%TYPE IS -- v_return intermediaries.NAME%TYPE; v_inte_id intermediaries.inte_id%TYPE; -- BEGIN -- v_inte_id := nvl(p_inte_id ,get_inte_id); FOR v_inte IN (SELECT NAME FROM intermediaries WHERE inte_id = v_inte_id) LOOP v_return := v_inte.NAME; END LOOP; -- RETURN nvl(v_return ,p_default); -- END get_inte_name; -- -- Get hash value -- FUNCTION get_hash_value(p_hash_key IN t_hash_key) RETURN t_hash_value IS v_hash_value t_hash_value; BEGIN v_hash_value := dbms_utility.get_hash_value(p_hash_key ,c_hash_base ,c_hash_size); RETURN v_hash_value; END get_hash_value; -- -- Get Exception Message -- PROCEDURE get_exception_message(p_exception_number IN exception_messages.exception_number%TYPE ,p_message IN OUT exception_messages.message%TYPE ,p_exme_type IN OUT exception_messages.exme_type%TYPE ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list ,p_language IN system_users.language%TYPE DEFAULT caco_utilities.get_syus_lang) IS -- l_index PLS_INTEGER; l_def_lang VARCHAR2(2) := 'EN'; -- BEGIN -- BEGIN -- SELECT TO_CHAR(ABS(exception_number)) || ': ' || message ,exme_type INTO p_message ,p_exme_type FROM exception_messages WHERE exception_number = p_exception_number AND language = NVL(p_language, l_def_lang); -- EXCEPTION WHEN no_data_found THEN p_message := 'UNABLE TO FIND MESSAGE FOR EXCEPTION ' || to_char(p_exception_number); p_exme_type := 'E'; END; -- l_index := p_substitution_list.FIRST; -- LOOP -- EXIT WHEN l_index IS NULL; p_message := REPLACE(p_message ,'' ,p_substitution_list(l_index)); l_index := p_substitution_list.NEXT(l_index); -- END LOOP; -- END get_exception_message; -- PROCEDURE raise_exception_error(p_exception_number IN exception_messages.exception_number%TYPE ,p_substitution_list IN g_t_substitution_list DEFAULT c_empty_substitution_list) IS v_message exception_messages.message%TYPE; v_exme_type exception_messages.exme_type%TYPE; BEGIN get_exception_message(p_exception_number => p_exception_number ,p_message => v_message ,p_exme_type => v_exme_type ,p_substitution_list => p_substitution_list); raise_application_error(p_exception_number ,caco_utilities.get_system_name || v_exme_type || ' ' || v_message ,TRUE); END raise_exception_error; -- PROCEDURE raise_exception_error(p_exception_number IN exception_messages.exception_number%TYPE ,p_additional_message IN VARCHAR2) IS v_message exception_messages.message%TYPE; v_exme_type exception_messages.exme_type%TYPE; BEGIN get_exception_message(p_exception_number => p_exception_number ,p_message => v_message ,p_exme_type => v_exme_type); raise_application_error(p_exception_number ,caco_utilities.get_system_name || v_exme_type || ' ' || v_message || ':' || p_additional_message ,TRUE); END raise_exception_error; -- -- Generic error reporting procedure which will replace up to five -- characters ('') in message text with parameter values. -- PROCEDURE raise_exception_error_param(p_exception_number IN exception_messages.exception_number%TYPE ,p_substitution_list IN g_t_substitution_list DEFAULT c_empty_substitution_list) IS -- v_message exception_messages.message%TYPE; v_exme_type exception_messages.exme_type%TYPE; -- BEGIN -- get_exception_message(p_exception_number => p_exception_number ,p_message => v_message ,p_exme_type => v_exme_type ,p_substitution_list => p_substitution_list); raise_application_error(p_exception_number ,caco_utilities.get_system_name || v_exme_type || ' ' || v_message ,TRUE); -- END raise_exception_error_param; -- FUNCTION raise_error(p_error_number IN exception_messages.exception_number%TYPE ,p_substitution_list IN g_t_substitution_list DEFAULT c_empty_substitution_list) RETURN BOOLEAN IS -- v_message exception_messages.message%TYPE; v_exme_type exception_messages.exme_type%TYPE; -- BEGIN -- get_exception_message(p_exception_number => p_error_number ,p_message => v_message ,p_exme_type => v_exme_type ,p_substitution_list => p_substitution_list); cg$errors.push(msg => v_message ,error => v_exme_type ,msg_type => '' ,msgid => p_error_number ,loc => 'APPLICATION'); RETURN FALSE; -- END raise_error; FUNCTION get_ints(p_how_many IN NUMBER) RETURN t_int_array AS v_int_array t_int_array := t_int_array(); BEGIN FOR v_index IN 1 .. p_how_many LOOP v_int_array.EXTEND; v_int_array(v_index) := v_index; END LOOP; RETURN v_int_array; END get_ints; FUNCTION cgrefvalue(p_domain IN cg_ref_codes.rv_domain%TYPE ,p_meaning IN cg_ref_codes.rv_meaning%TYPE) RETURN VARCHAR2 IS CURSOR c_cgrc IS SELECT rv_low_value FROM cg_ref_codes WHERE rv_domain = p_domain AND rv_meaning = p_meaning; v_value cg_ref_codes.rv_low_value%TYPE; BEGIN FOR r_cgrc IN c_cgrc LOOP v_value := r_cgrc.rv_low_value; END LOOP; RETURN v_value; END cgrefvalue; FUNCTION cgrefmeaning(p_domain IN cg_ref_codes.rv_domain%TYPE ,p_value IN cg_ref_codes.rv_low_value%TYPE) RETURN VARCHAR2 IS CURSOR c_cgrc IS SELECT rv_meaning FROM cg_ref_codes WHERE rv_domain = p_domain AND rv_low_value = p_value; v_meaning cg_ref_codes.rv_meaning%TYPE; BEGIN FOR r_cgrc IN c_cgrc LOOP v_meaning := r_cgrc.rv_meaning; END LOOP; RETURN v_meaning; END cgrefmeaning; -- -- Function to return value of global package defined variable g_global_date -- FUNCTION get_global_date RETURN DATE IS BEGIN -- RETURN g_global_date; -- END get_global_date; -- FUNCTION get_syus_first_last_db_names(p_syus_id IN system_users.syus_id%TYPE) RETURN VARCHAR2 IS v_first_name system_users.first_name%TYPE; v_last_name system_users.last_name%TYPE; v_db_username system_users.db_username%TYPE; BEGIN SELECT first_name ,last_name ,db_username INTO v_first_name ,v_last_name ,v_db_username FROM system_users WHERE syus_id = p_syus_id; RETURN v_first_name || ' ' || v_last_name || ' ' || v_db_username; EXCEPTION WHEN no_data_found THEN RETURN 'ERROR- get_syus_first_last_db_names - syus_id ' || p_syus_id || ' NOT FOUND'; END get_syus_first_last_db_names; FUNCTION chk_overlap(p_requested_start IN DATE ,p_requested_end IN DATE ,p_existing_start IN DATE ,p_existing_end IN DATE) RETURN VARCHAR2 IS BEGIN IF ((p_requested_start >= p_existing_start AND p_requested_start < p_existing_end) OR (p_requested_end > p_existing_start AND p_requested_end <= p_existing_end) OR (p_existing_start >= p_requested_start AND p_existing_start < p_requested_end) OR (p_existing_end > p_requested_start AND p_existing_end <= p_requested_end)) THEN RETURN 'TRUE'; -- periods overlap ELSE RETURN 'FALSE'; -- no overlap END IF; END chk_overlap; -- -- FUNCTION get_module_text(p_text_number IN NUMBER ,p_language IN system_users.LANGUAGE%TYPE DEFAULT caco_utilities.get_syus_lang) RETURN VARCHAR IS -- v_return VARCHAR2(1000); v_def_lang VARCHAR2(2) := 'EN'; -- CURSOR cur_mt(p_text_number IN NUMBER, p_language IN system_users.LANGUAGE%TYPE) IS SELECT mt.text FROM module_text mt WHERE mt.text_number = p_text_number AND mt.LANGUAGE = p_language; -- BEGIN -- OPEN cur_mt(p_text_number ,nvl(p_language ,v_def_lang)); FETCH cur_mt INTO v_return; -- IF cur_mt%NOTFOUND THEN -- v_return := '***Text Not Found***'; -- END IF; -- CLOSE cur_mt; -- RETURN v_return; -- END get_module_text; -- PROCEDURE string_to_table(p_string IN VARCHAR2 ,p_delimiter IN VARCHAR2 := ',' ,p_table OUT t_string_table ,p_count OUT NUMBER) IS -- v_string VARCHAR2(2000) := p_string; v_delimiter_string VARCHAR2(80) := substr(p_delimiter ,1 ,80); v_delimiter VARCHAR2(1); v_from NUMBER := 1; v_to NUMBER; v_count NUMBER := 1; v_continue BOOLEAN := TRUE; FUNCTION instr_delimiter(p_string IN VARCHAR2 ,p_pos IN NUMBER ,p_delimiter_string IN VARCHAR2 ,p_delimiter_found OUT VARCHAR2) RETURN NUMBER IS v_return_delimiter VARCHAR2(1); v_return_pos NUMBER := 0; v_delimiter VARCHAR2(1); v_pos NUMBER := 0; BEGIN FOR v_index IN 1 .. length(p_delimiter_string) LOOP v_delimiter := substr(p_delimiter_string ,v_index ,1); v_pos := instr(p_string ,v_delimiter ,p_pos); IF v_pos > 0 AND (v_pos < v_return_pos OR v_return_pos = 0) THEN v_return_pos := v_pos; v_return_delimiter := v_delimiter; END IF; END LOOP; p_delimiter_found := v_return_delimiter; RETURN v_return_pos; END instr_delimiter; BEGIN p_count := 0; IF p_string IS NULL OR v_delimiter_string IS NULL THEN -- missing parameters p_table.DELETE; ELSIF instr_delimiter(p_string => p_string ,p_pos => 1 ,p_delimiter_string => v_delimiter_string ,p_delimiter_found => v_delimiter) = 0 THEN -- -- there are no delimiters in the given string -- p_table(1).stringpart := p_string; p_table(1).delimiter := NULL; p_count := 1; ELSE -- string and delimiter valid. BEGIN WHILE v_continue LOOP v_to := instr_delimiter(p_string => p_string ,p_pos => v_from ,p_delimiter_string => v_delimiter_string ,p_delimiter_found => v_delimiter); IF v_to = 0 THEN v_to := length(p_string) + 1; v_continue := FALSE; END IF; p_table(v_count).stringpart := substr(p_string ,v_from ,(v_to - v_from)); p_table(v_count).delimiter := v_delimiter; v_from := v_to + 1; v_count := v_count + 1; END LOOP; p_count := v_count - 1; END; IF instr(v_delimiter_string ,substr(p_string ,length(p_string) ,1)) < 1 THEN -- -- the last string did not end with a delimiter -- p_table(p_count).delimiter := NULL; END IF; END IF; END string_to_table; FUNCTION translate_lang(p_text IN VARCHAR2 ,p_language_source IN VARCHAR2 DEFAULT 'EN' ,p_language_destination IN VARCHAR2 DEFAULT 'EN') RETURN VARCHAR2 IS v_string_table t_string_table; v_string_count NUMBER; v_return_string VARCHAR2(32767); FUNCTION translate_string(p_text IN VARCHAR2 ,p_language_source IN module_text.LANGUAGE%TYPE DEFAULT 'EN' ,p_language_destination IN module_text.LANGUAGE%TYPE DEFAULT 'EN') RETURN module_text.text%TYPE IS v_trans_string VARCHAR2(4000); BEGIN SELECT utl_http.request('http://translate.google.com/translate_t?text=' || REPLACE(p_text ,' ' ,'%20') || '&langpair=' || p_language_source || '%7C' || lower(p_language_destination) || '&hl=en&ie=ISO-8859-1' ,'heat:8080') INTO v_trans_string FROM dual; v_trans_string := substr(v_trans_string ,instr(v_trans_string ,'PHYSICAL>') + 9 ,instr(substr(v_trans_string ,instr(v_trans_string ,'PHYSICAL>') + 9) ,'') - 1); RETURN v_trans_string; END translate_string; BEGIN string_to_table(p_string => p_text ,p_delimiter => ':;"' ,p_table => v_string_table ,p_count => v_string_count); FOR v_index IN 1 .. v_string_count LOOP IF NOT v_string_table(v_index).stringpart IS NULL THEN v_return_string := v_return_string || translate_string(p_text => v_string_table(v_index) .stringpart ,p_language_source => p_language_source ,p_language_destination => p_language_destination) || v_string_table(v_index).delimiter; ELSE v_return_string := v_return_string || v_string_table(v_index) .delimiter; END IF; END LOOP; RETURN v_return_string; END translate_lang; FUNCTION add_module_text(p_text IN module_text.text%TYPE ,p_language IN module_text.LANGUAGE%TYPE) RETURN module_text.text_number%TYPE IS v_text_number module_text.text_number%TYPE; v_text_already_exists BOOLEAN DEFAULT TRUE; v_text module_text.text%TYPE; BEGIN BEGIN SELECT text_number INTO v_text_number FROM module_text WHERE text = p_text AND LANGUAGE = p_language; EXCEPTION WHEN no_data_found THEN -- -- need to add the text -- v_text_already_exists := FALSE; END; IF NOT v_text_already_exists THEN INSERT INTO module_text (text_number ,text ,LANGUAGE) VALUES (mtxt_num_seq.NEXTVAL ,p_text ,p_language) RETURNING text_number INTO v_text_number; END IF; DELETE FROM module_text WHERE text_number = v_text_number AND LANGUAGE <> p_language; FOR v_languages IN (SELECT rv_low_value LANGUAGE FROM cg_ref_codes WHERE rv_domain = 'LANGUAGE' AND rv_low_value <> p_language) LOOP v_text := substr(translate_lang(p_text => p_text ,p_language_source => p_language ,p_language_destination => v_languages.LANGUAGE) ,1 ,500); INSERT INTO module_text (text_number ,text ,LANGUAGE) VALUES (v_text_number ,v_text ,v_languages.LANGUAGE); END LOOP; RETURN v_text_number; END add_module_text; PROCEDURE html_email(p_to IN VARCHAR2 DEFAULT cout_system_configuration.get_configuration_item('CONTACT_EMAIL') ,p_from IN VARCHAR2 DEFAULT caco_utilities.get_system_name ,p_subject IN VARCHAR2 DEFAULT 'Fax Message from ' || caco_utilities.get_system_name ,p_text IN VARCHAR2 DEFAULT NULL ,p_html IN VARCHAR2 DEFAULT NULL ,p_smtp_hostname IN VARCHAR2 DEFAULT cout_system_configuration.get_configuration_item('SYSTEM_SMTP_SERVER') ,p_smtp_portnum IN VARCHAR2 DEFAULT cout_system_configuration.get_configuration_item('SYSTEM_SMTP_PORT')) IS -- l_boundary VARCHAR2(255) DEFAULT 'a1b2c3d4e3f2g1'; l_connection utl_smtp.connection; l_body_html CLOB := empty_clob; --This LOB will be the email message l_offset NUMBER; l_ammount NUMBER; l_temp VARCHAR2(32767) DEFAULT NULL; -- BEGIN -- l_connection := utl_smtp.open_connection(p_smtp_hostname ,p_smtp_portnum); utl_smtp.helo(l_connection ,p_smtp_hostname); utl_smtp.mail(l_connection ,p_from); utl_smtp.rcpt(l_connection ,p_to); -- l_temp := l_temp || 'MIME-Version: 1.0' || chr(13) || chr(10); l_temp := l_temp || 'To: ' || p_to || chr(13) || chr(10); l_temp := l_temp || 'From: ' || p_from || chr(13) || chr(10); l_temp := l_temp || 'Subject: ' || p_subject || chr(13) || chr(10); l_temp := l_temp || 'Reply-To: ' || p_from || chr(13) || chr(10); l_temp := l_temp || 'Content-Type: multipart/alternative; boundary=' || chr(34) || l_boundary || chr(34) || chr(13) || chr(10); -- Write the headers dbms_lob.createtemporary(l_body_html ,FALSE ,10); dbms_lob.WRITE(l_body_html ,length(l_temp) ,1 ,l_temp); -- Write the text boundary l_offset := dbms_lob.getlength(l_body_html) + 1; l_temp := '--' || l_boundary || chr(13) || chr(10); l_temp := l_temp || 'content-type: text/plain; charset=us-ascii' || chr(13) || chr(10) || chr(13) || chr(10); dbms_lob.WRITE(l_body_html ,length(l_temp) ,l_offset ,l_temp); -- Write the plain text portion of the email l_offset := dbms_lob.getlength(l_body_html) + 1; dbms_lob.WRITE(l_body_html ,length(p_text) ,l_offset ,p_text); -- Write the HTML boundary l_temp := chr(13) || chr(10) || chr(13) || chr(10) || '--' || l_boundary || chr(13) || chr(10); l_temp := l_temp || 'content-type: text/html;' || chr(13) || chr(10) || chr(13) || chr(10); l_offset := dbms_lob.getlength(l_body_html) + 1; dbms_lob.WRITE(l_body_html ,length(l_temp) ,l_offset ,l_temp); -- Write the HTML portion of the message l_offset := dbms_lob.getlength(l_body_html) + 1; dbms_lob.WRITE(l_body_html ,length(p_html) ,l_offset ,p_html); -- Write the final html boundary l_temp := chr(13) || chr(10) || '--' || l_boundary || '--' || chr(13); l_offset := dbms_lob.getlength(l_body_html) + 1; dbms_lob.WRITE(l_body_html ,length(l_temp) ,l_offset ,l_temp); -- Send the email in 1900 byte chunks to UTL_SMTP l_offset := 1; l_ammount := 1900; utl_smtp.open_data(l_connection); WHILE l_offset < dbms_lob.getlength(l_body_html) LOOP utl_smtp.write_data(l_connection ,dbms_lob.substr(l_body_html ,l_ammount ,l_offset)); l_offset := l_offset + l_ammount; l_ammount := least(1900 ,dbms_lob.getlength(l_body_html) - l_ammount); END LOOP; utl_smtp.close_data(l_connection); utl_smtp.quit(l_connection); dbms_lob.freetemporary(l_body_html); -- END html_email; -- FUNCTION convert_date_to_gas_day(p_date IN DATE) RETURN DATE IS BEGIN -- RETURN(cout_dates.convert_date_to_gas_day(p_date => p_date)); -- END convert_date_to_gas_day; -- -- Pass in the gas day and get the number of hours in it -- FUNCTION get_dst_hours(p_gas_day IN DATE) RETURN NUMBER IS -- BEGIN -- RETURN(cout_dates.get_dst_hours(p_gas_day => p_gas_day)); -- END get_dst_hours; -- FUNCTION get_hours(p_gas_day IN DATE) RETURN t_int_array AS -- BEGIN RETURN(cout_dates.get_hours(trunc(p_gas_day))); -- END get_hours; -- -- Check sequential dates -- FUNCTION check_dates(p_period_start IN DATE ,p_period_end IN DATE ,p_check_past IN BOOLEAN) RETURN BOOLEAN IS -- l_ret_val BOOLEAN; -- BEGIN -- IF p_period_start < trunc(SYSDATE) AND p_check_past THEN -- l_ret_val := caco_utilities.raise_error(-20007); -- ELSIF p_period_end < p_period_start THEN -- l_ret_val := caco_utilities.raise_error(-20008); -- ELSE -- l_ret_val := TRUE; -- END IF; -- RETURN l_ret_val; -- END check_dates; --- -- C U T Y C O D E F O R C U S T --- FUNCTION cuty_code_for_cust(p_cust_id IN customers.cust_id%TYPE) RETURN customer_types.code%TYPE IS -- CURSOR c_cuty IS SELECT cuty.code FROM customer_types cuty, customers cust WHERE cuty.cuty_id = cust.cuty_id AND cust.cuty_id = p_cust_id; -- l_cuty_code customer_types.code%TYPE; -- BEGIN -- OPEN c_cuty; FETCH c_cuty INTO l_cuty_Code; CLOSE c_cuty; --- -- Will return NULL if no data found. --- RETURN (l_cuty_code); -- END; --- -- C U T Y C O D E F O R U S E R --- FUNCTION cuty_code_for_user RETURN customer_types.code%TYPE IS -- CURSOR c_cuty IS SELECT cuty.code FROM customer_types cuty, customers cust WHERE cuty.cuty_id = cust.cuty_id AND cust.cust_id = caco_utilities.get_cust_id; -- Gets the customer the user is acting for -- l_cuty_code customer_types.code%TYPE; -- BEGIN -- OPEN c_cuty; FETCH c_cuty INTO l_cuty_Code; CLOSE c_cuty; --- -- Will return NULL if no data found. --- RETURN (l_cuty_code); -- END; --- -- C U T Y I D F O R U S E R --- FUNCTION cuty_id_for_user RETURN customer_types.cuty_id%TYPE IS -- CURSOR c_cuty IS SELECT cuty.cuty_id FROM customer_types cuty, customers cust WHERE cuty.cuty_id = cust.cuty_id AND cust.cust_id = caco_utilities.get_cust_id; -- Gets the customer the user is acting for -- l_cuty_id customer_types.cuty_id%TYPE; -- BEGIN -- OPEN c_cuty; FETCH c_cuty INTO l_cuty_id; CLOSE c_cuty; --- -- Will return NULL if no data found. --- RETURN (l_cuty_id); -- EXCEPTION WHEN others THEN RETURN NULL; END; --- -- U S E R H A S S Y S T E M --- FUNCTION user_has_system RETURN VARCHAR2 IS -- CURSOR c_system_user IS SELECT COUNT(1) FROM user_profiles uspr, system_profiles sypr WHERE sypr.sypr_id = uspr.sypr_id AND uspr.syus_id = caco_utilities.get_syus_id AND sypr.name = 'SYSTEM'; -- l_count NUMBER; l_flag VARCHAR2(1); -- BEGIN -- l_flag := NULL; -- OPEN c_system_user; FETCH c_system_user INTO l_count; CLOSE c_system_user; -- IF (l_count > 0) THEN -- l_flag := C_Yes; -- ELSE -- l_flag := C_No; -- END IF; -- RETURN (l_flag); -- END ; --- -- --- FUNCTION user_has_EFT_admin RETURN VARCHAR2 IS -- CURSOR c_EFT_admin_user IS SELECT COUNT(1) FROM user_profiles uspr, system_profiles sypr WHERE sypr.sypr_id = uspr.sypr_id AND uspr.syus_id = caco_utilities.get_syus_id AND UPPER(sypr.name) IN ('EFT ADMIN', 'USER ADMIN'); -- l_count NUMBER; l_flag VARCHAR2(1); -- BEGIN -- l_flag := NULL; -- OPEN c_EFT_admin_user; FETCH c_EFT_admin_user INTO l_count; CLOSE c_EFT_admin_user; -- IF (l_count > 0) THEN -- l_flag := C_Yes; -- ELSE -- l_flag := C_No; -- END IF; -- RETURN (l_flag); -- END; -- FUNCTION get_nepo_name(p_nepo_id IN network_points.nepo_id%TYPE DEFAULT NULL) RETURN network_points.name%TYPE IS -- CURSOR cur_nepo(p_nepo_id IN network_points.nepo_id%TYPE) IS SELECT nepo.name FROM network_points nepo WHERE nepo.nepo_id = p_nepo_id; -- v_return network_points.name%TYPE; -- BEGIN -- OPEN cur_nepo(p_nepo_id); FETCH cur_nepo INTO v_return; CLOSE cur_nepo; -- RETURN nvl(v_return ,'No Network Point Name'); -- END get_nepo_name; -- FUNCTION to_thousand_separated(p_val IN VARCHAR2) RETURN VARCHAR2 IS BEGIN RETURN REPLACE(to_char(to_number(p_val),g_number_format),',',g_thousand_separator); -- EXCEPTION WHEN OTHERS THEN -- cout_err.report_and_stop(p_exception_message => sqlerrm||' IN caco_utilities.to_thousand_separated(varchar2)'); -- END to_thousand_separated; -- FUNCTION to_thousand_separated(p_val IN NUMBER) RETURN VARCHAR2 IS BEGIN RETURN REPLACE(to_char(p_val,g_number_format),',',g_thousand_separator); -- EXCEPTION WHEN OTHERS THEN -- cout_err.report_and_stop(p_exception_message => sqlerrm||' IN caco_utilities.to_thousand_separated(number)'); -- END to_thousand_separated; -- FUNCTION thousand_separated_to_num(p_val IN VARCHAR2) RETURN NUMBER IS BEGIN RETURN to_number(REPLACE(p_val,g_thousand_separator,NULL)); -- EXCEPTION WHEN OTHERS THEN -- cout_err.report_and_stop(p_exception_message => sqlerrm||' IN caco_utilities.thousand_separated_to_num'); -- END thousand_separated_to_num; -- FUNCTION thousand_separated_to_char(p_val IN VARCHAR2) RETURN VARCHAR2 IS BEGIN RETURN REPLACE(p_val,g_thousand_separator,NULL); -- EXCEPTION WHEN OTHERS THEN -- cout_err.report_and_stop(p_exception_message => sqlerrm||' IN caco_utilities.thousand_separated_to_char'); -- END thousand_separated_to_char; -- FUNCTION thousand_separated_to_char(p_val IN owa_util.vc_arr) RETURN owa_util.vc_arr IS -- l_return owa_util.vc_arr; -- BEGIN -- FOR i IN 1..p_val.COUNT LOOP l_return(i) := REPLACE(p_val(i),g_thousand_separator,NULL); END LOOP; -- RETURN l_return; -- EXCEPTION WHEN OTHERS THEN -- cout_err.report_and_stop(p_exception_message => sqlerrm||' IN caco_utilities.thousand_separated_to_char(owa_util.vc_arr)'); -- END thousand_separated_to_char; -- PROCEDURE thousand_separator_js IS BEGIN htp.p(' function thousandSeparator(x,sValue) { var sRegExp = new RegExp(''(-?[0-9]+)([0-9]{3})'') var sep = " " while(sRegExp.test(sValue)) { sValue = sValue.replace(sRegExp, ''$1''+sep+''$2'') } document.getElementById(x).value= sValue }'); END thousand_separator_js; -- FUNCTION output_form_buttons RETURN VARCHAR2 IS BEGIN -- RETURN '

'; END output_form_buttons; -- FUNCTION efnow010_output_form_buttons RETURN VARCHAR2 IS BEGIN -- RETURN '

'||output_form_buttons; END efnow010_output_form_buttons; -- FUNCTION efnow020_output_form_buttons RETURN VARCHAR2 IS BEGIN -- RETURN ' '||output_form_buttons; END efnow020_output_form_buttons; -- END caco_utilities; /