CREATE OR REPLACE PACKAGE BODY efno_msgsubs IS -- -- Public Procedures -- FUNCTION count_suca RETURN NUMBER IS l_count NUMBER := 0; BEGIN -- IF NOT caco_security.security_check('efnow097$') THEN RETURN 0; END IF; -- SELECT COUNT(*) INTO l_count FROM subscription_categories; -- RETURN l_count; -- END count_suca; -- FUNCTION get_suca_id(p_suca_group IN VARCHAR2 DEFAULT NULL ,p_suca_name IN VARCHAR2 DEFAULT NULL) RETURN subscription_categories.suca_id%TYPE IS CURSOR c_suca IS SELECT suca_id FROM subscription_categories WHERE upper(name_en) = upper(nvl(p_suca_name ,'&^%"%')) AND upper(nvl(msg_group_en ,'A')) = upper(nvl(p_suca_group ,'A')); -- l_suca_id subscription_categories.suca_id%TYPE := NULL; -- BEGIN -- OPEN c_suca; FETCH c_suca INTO l_suca_id; CLOSE c_suca; -- RETURN nvl(l_suca_id ,0); -- END get_suca_id; -- PROCEDURE send_messages(p_cust_id IN customers.cust_id%TYPE ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_email_content_en IN VARCHAR2 ,p_email_content_hu IN VARCHAR2 DEFAULT NULL ,p_email_subject_en IN VARCHAR2 DEFAULT NULL ,p_email_subject_hu IN VARCHAR2 DEFAULT NULL ,p_sms_content_en IN VARCHAR2 DEFAULT NULL ,p_sms_content_hu IN VARCHAR2 DEFAULT NULL ,p_file IN BLOB DEFAULT NULL ,p_filename IN VARCHAR2 DEFAULT NULL ,p_file_mime_type IN VARCHAR2 DEFAULT NULL) IS -- -- Cursor to grab all the user contact details for this customer and message subscription category -- CURSOR c_uscd IS SELECT suco.uscd_id uscd_id ,uscd.syus_id syus_id ,suco.TYPE TYPE ,uscd.email_address email_address ,uscd.sms_number sms_number FROM subscription_contacts suco ,user_contact_details uscd ,system_users syus WHERE syus.cust_id = p_cust_id AND syus.syus_id = uscd.syus_id AND uscd.uscd_id = suco.uscd_id AND suco.suca_id = p_suca_id AND syus.period_start < SYSDATE AND (syus.period_end > SYSDATE OR syus.period_end IS NULL) AND syus.user_locked = 'N'; -- -- Cursor to get the email subject description for the given Subscription Category -- CURSOR c_suca IS SELECT description_en ,description_hu FROM subscription_categories WHERE suca_id = p_suca_id; -- l_suca_rec c_suca%ROWTYPE; l_email_subject VARCHAR2(4000); l_email_content VARCHAR2(32767); l_sms_msg VARCHAR2(160); l_sys_lang system_users.LANGUAGE%TYPE := 'EN'; -- BEGIN -- OPEN c_suca; FETCH c_suca INTO l_suca_rec; CLOSE c_suca; -- -- So loop through the folk who want to receive this info and send it -- FOR r IN c_uscd LOOP -- l_email_subject := NULL; l_email_content := NULL; l_sms_msg := NULL; -- l_sys_lang := caco_utilities.get_syus_lang(r.syus_id); -- -- set the email content -- IF nvl(l_sys_lang ,'&%') = 'HU' AND p_email_content_hu IS NOT NULL THEN l_email_subject := nvl(p_email_subject_hu ,l_suca_rec.description_hu); l_email_content := p_email_content_hu; ELSE l_email_subject := nvl(p_email_subject_en ,l_suca_rec.description_en); l_email_content := p_email_content_en; END IF; -- -- Set the SMS content -- IF nvl(l_sys_lang ,'&%') = 'HU' AND p_sms_content_hu IS NOT NULL THEN l_sms_msg := p_sms_content_hu; ELSE l_sms_msg := p_sms_content_en; END IF; -- IF r.TYPE = 'EMAIL' THEN -- amfr_messaging.send_background_email(from_name => cout_system_configuration.get_configuration_item('CONTACT_EMAIL') ,to_names => r.email_address ,subject => l_email_subject ,message => l_email_content ,filename => p_filename ,file_mime_type => p_file_mime_type ,filecontents => p_file); -- ELSIF r.TYPE = 'SMS' AND l_sms_msg IS NOT NULL AND r.sms_number IS NOT NULL THEN -- amfr_messaging.send_sms_message(p_sms_number => r.sms_number ,p_sms_message => l_sms_msg); -- END IF; -- END LOOP; -- END send_messages; PROCEDURE send_messages(p_syus_id IN system_users.syus_id%TYPE ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_email_content_en IN VARCHAR2 ,p_email_content_hu IN VARCHAR2 DEFAULT NULL ,p_email_subject_en IN VARCHAR2 DEFAULT NULL ,p_email_subject_hu IN VARCHAR2 DEFAULT NULL ,p_sms_content_en IN VARCHAR2 DEFAULT NULL ,p_sms_content_hu IN VARCHAR2 DEFAULT NULL ,p_file IN BLOB DEFAULT NULL ,p_filename IN VARCHAR2 DEFAULT NULL ,p_file_mime_type IN VARCHAR2 DEFAULT NULL) IS -- Cursor to grab all the user contact details for this customer and message subscription category CURSOR c_uscd IS SELECT suco.uscd_id uscd_id ,uscd.syus_id syus_id ,suco.TYPE TYPE ,uscd.email_address email_address ,uscd.sms_number sms_number FROM subscription_contacts suco ,user_contact_details uscd WHERE p_syus_id = uscd.syus_id AND uscd.uscd_id = suco.uscd_id AND suco.suca_id = p_suca_id; -- -- Cursor to get the email subject description for the given Subscription Category CURSOR c_suca IS SELECT description_en ,description_hu FROM subscription_categories WHERE suca_id = p_suca_id; -- l_suca_rec c_suca%ROWTYPE; l_email_subject VARCHAR2(4000); l_email_content VARCHAR2(32767); l_sms_msg VARCHAR2(160); l_sys_lang system_users.LANGUAGE%TYPE := 'EN'; -- BEGIN -- OPEN c_suca; FETCH c_suca INTO l_suca_rec; CLOSE c_suca; -- -- So loop through the folk who want to receive this info and send it! FOR r IN c_uscd LOOP -- l_email_subject := NULL; l_email_content := NULL; l_sms_msg := NULL; -- l_sys_lang := caco_utilities.get_syus_lang(r.syus_id); -- -- set the email content IF nvl(l_sys_lang ,'&%') = 'HU' AND p_email_content_hu IS NOT NULL THEN l_email_subject := nvl(p_email_subject_hu ,l_suca_rec.description_hu); l_email_content := p_email_content_hu; ELSE l_email_subject := nvl(p_email_subject_en ,l_suca_rec.description_en); l_email_content := p_email_content_en; END IF; -- -- Set the SMS content IF nvl(l_sys_lang ,'&%') = 'HU' AND p_sms_content_hu IS NOT NULL THEN l_sms_msg := p_sms_content_hu; ELSE l_sms_msg := p_sms_content_en; END IF; -- IF r.TYPE = 'EMAIL' THEN -- amfr_messaging.send_background_email(from_name => cout_system_configuration.get_configuration_item('CONTACT_EMAIL') ,to_names => r.email_address ,subject => l_email_subject ,message => l_email_content ,filename => p_filename ,file_mime_type => p_file_mime_type ,filecontents => p_file); -- ELSIF r.TYPE = 'SMS' AND l_sms_msg IS NOT NULL AND r.sms_number IS NOT NULL THEN -- amfr_messaging.send_sms_message(p_sms_number => r.sms_number ,p_sms_message => l_sms_msg); -- END IF; -- END LOOP; -- END send_messages; PROCEDURE send_recorded_messages(p_cust_id IN customers.cust_id%TYPE ,p_message_type IN VARCHAR2 ,p_message_id IN VARCHAR2 ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_email_content_en IN VARCHAR2 ,p_email_content_hu IN VARCHAR2 DEFAULT NULL ,p_email_subject_en IN VARCHAR2 DEFAULT NULL ,p_email_subject_hu IN VARCHAR2 DEFAULT NULL ,p_sms_content_en IN VARCHAR2 DEFAULT NULL ,p_sms_content_hu IN VARCHAR2 DEFAULT NULL ,p_file IN BLOB DEFAULT NULL ,p_filename IN VARCHAR2 DEFAULT NULL ,p_file_mime_type IN VARCHAR2 DEFAULT NULL) IS -- Cursor to grab all the user contact details for this customer and message subscription category CURSOR c_uscd IS SELECT suco.uscd_id uscd_id ,uscd.syus_id syus_id ,suco.TYPE TYPE ,uscd.email_address email_address ,uscd.sms_number sms_number FROM subscription_contacts suco ,user_contact_details uscd ,system_users syus WHERE syus.cust_id = p_cust_id AND syus.syus_id = uscd.syus_id AND uscd.uscd_id = suco.uscd_id AND suco.suca_id = p_suca_id; -- -- Cursor to get the email subject description for the given Subscription Category CURSOR c_suca IS SELECT description_en ,description_hu FROM subscription_categories WHERE suca_id = p_suca_id; -- CURSOR c_remh(p_type IN VARCHAR2, p_id IN VARCHAR2) IS SELECT remh.remh_id FROM rec_message_header remh WHERE remh.message_identifier = p_id AND remh.message_type = p_type; -- l_suca_rec c_suca%ROWTYPE; l_email_subject VARCHAR2(4000); l_email_content VARCHAR2(32767); l_sms_msg rec_message_details.message_subject%TYPE; l_sys_lang system_users.LANGUAGE%TYPE := 'EN'; -- l_remh_id rec_message_header.remh_id%TYPE; -- BEGIN -- OPEN c_remh(p_message_type ,p_message_id); FETCH c_remh INTO l_remh_id; -- IF c_remh%NOTFOUND THEN -- INSERT INTO rec_message_header (message_identifier ,message_type) VALUES (p_message_id ,p_message_type) RETURNING remh_id INTO l_remh_id; -- END IF; -- CLOSE c_remh; -- OPEN c_suca; FETCH c_suca INTO l_suca_rec; CLOSE c_suca; -- -- So loop through the folk who want to receive this info and send it! FOR r IN c_uscd LOOP -- l_email_subject := NULL; l_email_content := NULL; l_sms_msg := NULL; -- l_sys_lang := caco_utilities.get_syus_lang(r.syus_id); -- -- set the email content IF nvl(l_sys_lang ,'&%') = 'HU' AND p_email_content_hu IS NOT NULL THEN l_email_subject := nvl(p_email_subject_hu ,l_suca_rec.description_hu); l_email_content := p_email_content_hu; ELSE l_email_subject := nvl(p_email_subject_en ,l_suca_rec.description_en); l_email_content := p_email_content_en; END IF; -- -- Set the SMS content IF nvl(l_sys_lang ,'&%') = 'HU' AND p_sms_content_hu IS NOT NULL THEN l_sms_msg := SUBSTR(p_sms_content_hu, 1, 250); ELSE l_sms_msg := SUBSTR(p_sms_content_en, 1, 250); END IF; -- IF r.TYPE = 'EMAIL' THEN -- INSERT INTO rec_message_details (remh_id ,cust_id ,message_type ,message_recipient ,message_subject ,message_body ,message_attachment) VALUES (l_remh_id ,p_cust_id ,'e' ,r.email_address ,l_email_subject ,l_email_content ,p_file); -- amfr_messaging.send_background_email(from_name => cout_system_configuration.get_configuration_item('CONTACT_EMAIL') ,to_names => r.email_address ,subject => l_email_subject ,message => l_email_content ,filename => p_filename ,file_mime_type => p_file_mime_type ,filecontents => p_file); -- ELSIF r.TYPE = 'SMS' AND l_sms_msg IS NOT NULL AND r.sms_number IS NOT NULL THEN -- INSERT INTO rec_message_details (remh_id ,cust_id ,message_type ,message_recipient ,message_subject ,message_body ,message_attachment) VALUES (l_remh_id ,p_cust_id ,'s' ,r.sms_number ,l_sms_msg ,l_sms_msg ,NULL); -- amfr_messaging.send_sms_message(p_sms_number => r.sms_number ,p_sms_message => l_sms_msg); -- END IF; -- END LOOP; -- END send_recorded_messages; FUNCTION check_msg_subscription(p_uscd_id IN user_contact_details.uscd_id%TYPE ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_type IN VARCHAR2) RETURN BOOLEAN IS -- CURSOR c_suco IS SELECT 'X' FROM subscription_contacts WHERE uscd_id = p_uscd_id AND suca_id = p_suca_id AND TYPE = p_type; -- l_success BOOLEAN := TRUE; l_dummy VARCHAR2(1); -- BEGIN -- IF NOT caco_security.security_check('efnow097$') THEN RETURN FALSE; END IF; -- OPEN c_suco; FETCH c_suco INTO l_dummy; IF c_suco%NOTFOUND THEN l_success := FALSE; END IF; CLOSE c_suco; -- RETURN l_success; -- END check_msg_subscription; PROCEDURE insert_msgsub(p_uscd_id IN user_contact_details.uscd_id%TYPE ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_type IN subscription_contacts.TYPE%TYPE ,p_success OUT BOOLEAN ,p_err_msg OUT VARCHAR2) IS BEGIN -- p_success := TRUE; -- BEGIN INSERT INTO subscription_contacts (uscd_id ,suca_id ,TYPE) VALUES (p_uscd_id ,p_suca_id ,p_type); EXCEPTION WHEN dup_val_on_index THEN -- We already have it - so its not a problem (this shouldnt happen) NULL; WHEN OTHERS THEN p_success := FALSE; p_err_msg := caco_utilities.get_module_text(2218); -- An unexpected error has occurred while inserting message subscriptions. Please contact support caco_debug.putline('efno_msgsubs.insert_msgsub: Error: ' || SQLERRM(SQLCODE) || chr(10) || 'USCD_ID = ' || p_uscd_id || chr(10) || 'SUCA_ID = ' || p_suca_id || chr(10) || 'TYPE = ' || p_type); -- Write an error and carry on cout_err.report_and_go(p_exception_number => SQLCODE ,p_exception_message => 'Unexpected error: ' || SQLERRM(SQLCODE) || chr(10) || 'USCD_ID = ' || p_uscd_id || chr(10) || 'SUCA_ID = ' || p_suca_id || chr(10) || 'TYPE = ' || p_type ,p_source => 'efno_msgsubs.insert_msgsub'); -- END; -- END insert_msgsub; PROCEDURE delete_msgsub(p_uscd_id IN user_contact_details.uscd_id%TYPE ,p_suca_id IN subscription_categories.suca_id%TYPE ,p_type IN subscription_contacts.TYPE%TYPE ,p_success OUT BOOLEAN ,p_err_msg OUT VARCHAR2) IS BEGIN -- p_success := TRUE; -- BEGIN DELETE subscription_contacts WHERE uscd_id = p_uscd_id AND suca_id = p_suca_id AND TYPE = p_type; EXCEPTION WHEN OTHERS THEN p_success := FALSE; p_err_msg := caco_utilities.get_module_text(2220); -- An unexpected error has occurred while removing message subscriptions. Please contact support caco_debug.putline('efno_msgsubs.delete_msgsub: Error: ' || SQLERRM(SQLCODE) || chr(10) || 'USCD_ID = ' || p_uscd_id || chr(10) || 'SUCA_ID = ' || p_suca_id || chr(10) || 'TYPE = ' || p_type); -- Write an error and carry on cout_err.report_and_go(p_exception_number => SQLCODE ,p_exception_message => 'Unexpected error: ' || SQLERRM(SQLCODE) || chr(10) || 'USCD_ID = ' || p_uscd_id || chr(10) || 'SUCA_ID = ' || p_suca_id || chr(10) || 'TYPE = ' || p_type ,p_source => 'efno_msgsubs.delete_msgsub'); -- END; -- END delete_msgsub; PROCEDURE update_msg_subs(p_suca_count IN NUMBER DEFAULT 0 ,p_uscd IN owa_util.vc_arr DEFAULT g_vc_arr ,p_type IN owa_util.vc_arr DEFAULT g_vc_arr ,p_suca_id IN owa_util.vc_arr DEFAULT g_vc_arr ,p_suca_checked IN owa_util.vc_arr DEFAULT g_vc_arr) IS -- already_exists BOOLEAN := FALSE; l_current_suca_count NUMBER := 0; -- l_success BOOLEAN := TRUE; l_return_error VARCHAR2(255) := NULL; -- BEGIN -- IF NOT caco_security.security_check('efnow097$') THEN RETURN; END IF; -- -- Check the integrity of the supplied data IF p_suca_count > 0 AND nvl(p_uscd.COUNT ,0) > 0 AND nvl(p_type.COUNT ,0) = nvl(p_uscd.COUNT ,0) AND nvl(p_suca_id.COUNT ,0) = (nvl(p_uscd.COUNT ,0) * p_suca_count) AND nvl(p_suca_checked.COUNT ,0) = (nvl(p_uscd.COUNT ,0) * p_suca_count) THEN -- All things look good - nothing to do here - its easier to check this way round NULL; ELSE l_success := FALSE; l_return_error := caco_utilities.get_module_text(2211); -- An unexpected error has occurred - invalid data. Please try again END IF; -- IF l_success THEN -- <> FOR i IN 1 .. p_uscd.COUNT LOOP -- l_current_suca_count := (i - 1) * p_suca_count; -- FOR j IN 1 .. p_suca_count LOOP -- already_exists := check_msg_subscription(p_uscd_id => p_uscd(i) ,p_suca_id => p_suca_id(l_current_suca_count + j) ,p_type => p_type(i)); -- IF already_exists THEN IF p_suca_checked(l_current_suca_count + j) = 'N' THEN -- DELETE the item delete_msgsub(p_uscd_id => p_uscd(i) ,p_suca_id => p_suca_id(l_current_suca_count + j) ,p_type => p_type(i) ,p_success => l_success ,p_err_msg => l_return_error); -- END IF; ELSE IF p_suca_checked(l_current_suca_count + j) = 'Y' THEN -- INSERT the item insert_msgsub(p_uscd_id => p_uscd(i) ,p_suca_id => p_suca_id(l_current_suca_count + j) ,p_type => p_type(i) ,p_success => l_success ,p_err_msg => l_return_error); END IF; END IF; -- IF NOT l_success THEN EXIT uscd_loop; END IF; -- END LOOP; -- END LOOP uscd_loop; -- END IF; -- Successfully passed data -- IF l_success THEN COMMIT; efnow097$.startup(p_success => 'Y'); ELSE ROLLBACK; efnow097$.startup(p_error => 'Y' ,p_err_msg => l_return_error); END IF; -- END update_msg_subs; /** -- 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_msgsubs; /