├── LICENSE ├── README.md ├── clicksend_pkg.pkb ├── clicksend_pkg.pks ├── clicksend_pkg_with_logger.pkb ├── create_tables.sql ├── create_types.sql ├── examples.sql ├── grants.sql ├── install.sql ├── install_with_logger.sql └── uninstall.sql /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2016 Jeffrey Kemp 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # clicksend-plsql-api # 2 | 3 | ## Oracle PL/SQL API for Clicksend ## 4 | 5 | Send transactional messages from your Oracle database to anyone with a phone, via **[Clicksend](https://www.clicksend.com)**. 6 | 7 | * **SMS** (Short Message Service) 8 | 9 | * **MMS** (Multimedia Message Service) 10 | 11 | * Text to **Voice** 12 | 13 | ## LINKS ## 14 | 15 | * **[Home page](https://jeffreykemp.github.io/clicksend-plsql-api/)** 16 | 17 | * Installation instructions, detailed API references and example code: **[WIKI](https://github.com/jeffreykemp/clicksend-plsql-api/wiki)** 18 | 19 | * Related blog post: 20 | -------------------------------------------------------------------------------- /clicksend_pkg.pkb: -------------------------------------------------------------------------------- 1 | create or replace package body clicksend_pkg as 2 | /* Clicksend API v0.3 3 | https://github.com/jeffreykemp/clicksend-plsql-api 4 | by Jeffrey Kemp 5 | */ 6 | 7 | queue_name constant varchar2(500) := sys_context('userenv','current_schema')||'.clicksend_queue'; 8 | queue_table constant varchar2(500) := sys_context('userenv','current_schema')||'.clicksend_queue_tab'; 9 | job_name constant varchar2(30) := 'clicksend_process_queue'; 10 | purge_job_name constant varchar2(30) := 'clicksend_purge_logs'; 11 | payload_type constant varchar2(500) := sys_context('userenv','current_schema')||'.t_clicksend_msg'; 12 | max_dequeue_count constant integer := 1000; -- max messages processed by push_queue in one go 13 | 14 | -- defaults to use if init() not used to set these settings 15 | default_country constant varchar2(10) := 'AU'; 16 | default_api_url constant varchar2(200) := 'https://rest.clicksend.com/v3/'; 17 | default_voice_lang constant varchar2(10) := 'en-au'; -- aussie 18 | default_voice_gender constant varchar2(6) := 'female'; 19 | default_voice_preamble constant varchar2(500) := '.....'; -- add a pause at the start 20 | default_log_retention_days constant number := 30; 21 | default_queue_expiration constant integer := 24 * 60 * 60; -- failed messages expire from the queue after 24 hours 22 | 23 | -- message types 24 | message_type_sms constant varchar2(20) := 'sms'; 25 | message_type_mms constant varchar2(20) := 'mms'; 26 | message_type_voice constant varchar2(20) := 'voice'; 27 | 28 | -- setting names 29 | setting_clicksend_username constant varchar2(100) := 'clicksend_username'; 30 | setting_clicksend_secret_key constant varchar2(100) := 'clicksend_secret_key'; 31 | setting_api_url constant varchar2(100) := 'api_url'; 32 | setting_wallet_path constant varchar2(100) := 'wallet_path'; 33 | setting_wallet_password constant varchar2(100) := 'wallet_password'; 34 | setting_log_retention_days constant varchar2(100) := 'log_retention_days'; 35 | setting_default_sender constant varchar2(100) := 'default_sender'; 36 | setting_default_country constant varchar2(100) := 'default_country'; 37 | setting_default_voice_lang constant varchar2(100) := 'default_voice_lang'; 38 | setting_default_voice_gender constant varchar2(100) := 'default_voice_gender'; 39 | setting_voice_preamble constant varchar2(100) := 'voice_preamble'; 40 | setting_queue_expiration constant varchar2(100) := 'queue_expiration'; 41 | setting_prod_instance_name constant varchar2(100) := 'prod_instance_name'; 42 | setting_non_prod_recipient constant varchar2(100) := 'non_prod_recipient'; 43 | 44 | type t_key_val_arr is table of varchar2(4000) index by varchar2(100); 45 | 46 | g_setting t_key_val_arr; 47 | 48 | e_no_queue_data exception; 49 | pragma exception_init (e_no_queue_data, -25228); 50 | 51 | -------------------------------------------------------------------------------- 52 | --------------------------------- PRIVATE METHODS ------------------------------ 53 | -------------------------------------------------------------------------------- 54 | 55 | procedure assert (cond in boolean, err in varchar2) is 56 | begin 57 | if not cond then 58 | raise_application_error(-20000, $$plsql_unit || ' assertion failed: ' || err); 59 | end if; 60 | end assert; 61 | 62 | -- set or update a setting 63 | procedure set_setting 64 | (p_name in varchar2 65 | ,p_value in varchar2 66 | ) is 67 | begin 68 | 69 | assert(p_name is not null, 'p_name cannot be null'); 70 | 71 | merge into clicksend_settings t 72 | using (select p_name as setting_name 73 | ,p_value as setting_value 74 | from dual) s 75 | on (t.setting_name = s.setting_name) 76 | when matched then 77 | update set t.setting_value = s.setting_value 78 | when not matched then 79 | insert (setting_name, setting_value) 80 | values (s.setting_name, s.setting_value); 81 | 82 | commit; 83 | 84 | end set_setting; 85 | 86 | -- retrieve all the settings for a normal session 87 | procedure load_settings is 88 | begin 89 | 90 | -- set defaults first 91 | g_setting(setting_api_url) := default_api_url; 92 | g_setting(setting_wallet_path) := ''; 93 | g_setting(setting_wallet_password) := ''; 94 | g_setting(setting_log_retention_days) := default_log_retention_days; 95 | g_setting(setting_default_sender) := ''; 96 | g_setting(setting_default_country) := default_country; 97 | g_setting(setting_default_voice_lang) := default_voice_lang; 98 | g_setting(setting_default_voice_gender) := default_voice_gender; 99 | g_setting(setting_voice_preamble) := default_voice_preamble; 100 | g_setting(setting_queue_expiration) := default_queue_expiration; 101 | g_setting(setting_prod_instance_name) := ''; 102 | g_setting(setting_non_prod_recipient) := ''; 103 | 104 | for r in ( 105 | select s.setting_name 106 | ,s.setting_value 107 | from clicksend_settings s 108 | ) loop 109 | 110 | g_setting(r.setting_name) := r.setting_value; 111 | 112 | end loop; 113 | 114 | end load_settings; 115 | 116 | procedure reset is 117 | begin 118 | 119 | g_setting.delete; 120 | 121 | end reset; 122 | 123 | -- get a setting 124 | -- if p_default is set, a null/not found will return the default value 125 | -- if p_default is null, a not found will raise an exception 126 | function setting (p_name in varchar2) return varchar2 is 127 | p_value clicksend_settings.setting_value%type; 128 | begin 129 | 130 | assert(p_name is not null, 'p_name cannot be null'); 131 | 132 | -- prime the settings array for this session 133 | if g_setting.count = 0 then 134 | load_settings; 135 | end if; 136 | 137 | p_value := g_setting(p_name); 138 | 139 | return p_value; 140 | exception 141 | when no_data_found then 142 | raise_application_error(-20000, 'clicksend setting not set "' || p_name || '" - please setup using ' || $$plsql_unit || '.init()'); 143 | end setting; 144 | 145 | function log_retention_days return number is 146 | begin 147 | return to_number(setting(setting_log_retention_days)); 148 | end log_retention_days; 149 | 150 | procedure prod_check 151 | (p_is_prod out boolean 152 | ,p_non_prod_recipient out varchar2 153 | ) is 154 | prod_instance_name clicksend_settings.setting_value%type; 155 | begin 156 | 157 | prod_instance_name := setting(setting_prod_instance_name); 158 | 159 | if prod_instance_name is not null then 160 | p_is_prod := (prod_instance_name = sys_context('userenv','db_name')); 161 | else 162 | p_is_prod := true; -- if setting not set, we treat this as a prod env 163 | end if; 164 | 165 | if not p_is_prod then 166 | p_non_prod_recipient := setting(setting_non_prod_recipient); 167 | end if; 168 | 169 | end prod_check; 170 | 171 | procedure set_wallet is 172 | wallet_path varchar2(4000); 173 | wallet_password varchar2(4000); 174 | begin 175 | 176 | wallet_path := setting(setting_wallet_path); 177 | wallet_password := setting(setting_wallet_password); 178 | 179 | if wallet_path is not null or wallet_password is not null then 180 | sys.utl_http.set_wallet(wallet_path, wallet_password); 181 | end if; 182 | 183 | end set_wallet; 184 | 185 | function get_response (resp in out nocopy sys.utl_http.resp) return clob is 186 | buf varchar2(32767); 187 | ret clob := empty_clob; 188 | begin 189 | 190 | sys.dbms_lob.createtemporary(ret, true); 191 | 192 | begin 193 | loop 194 | sys.utl_http.read_text(resp, buf, 32767); 195 | sys.dbms_lob.writeappend(ret, length(buf), buf); 196 | end loop; 197 | exception 198 | when sys.utl_http.end_of_body then 199 | null; 200 | end; 201 | sys.utl_http.end_response(resp); 202 | 203 | return ret; 204 | end get_response; 205 | 206 | function get_json 207 | (p_url in varchar2 208 | ,p_method in varchar2 209 | ,p_params in varchar2 := null 210 | ,p_data in varchar2 := null 211 | ,p_user in varchar2 := null 212 | ,p_pwd in varchar2 := null 213 | ,p_accept in varchar2 := null 214 | ) return clob is 215 | url varchar2(4000) := p_url; 216 | req sys.utl_http.req; 217 | resp sys.utl_http.resp; 218 | ret clob; 219 | begin 220 | 221 | assert(p_url is not null, 'get_json: p_url cannot be null'); 222 | 223 | set_wallet; 224 | 225 | if p_params is not null then 226 | url := url || '?' || p_params; 227 | end if; 228 | 229 | req := sys.utl_http.begin_request(url => url, method => p_method); 230 | 231 | if p_user is not null or p_pwd is not null then 232 | sys.utl_http.set_authentication(req, p_user, p_pwd); 233 | end if; 234 | 235 | if p_data is not null then 236 | sys.utl_http.set_header (req,'Content-Type','application/json'); 237 | sys.utl_http.set_header (req,'Content-Length',length(p_data)); 238 | sys.utl_http.write_text (req,p_data); 239 | end if; 240 | 241 | if p_accept is not null then 242 | sys.utl_http.set_header (req,'Accept',p_accept); 243 | end if; 244 | 245 | resp := sys.utl_http.get_response(req); 246 | 247 | if resp.status_code != '200' then 248 | raise_application_error(-20000, 'get_json call failed ' || resp.status_code || ' ' || resp.reason_phrase || ' [' || url || ']'); 249 | end if; 250 | 251 | ret := get_response(resp); 252 | 253 | return ret; 254 | end get_json; 255 | 256 | function get_epoch (p_date in date) return number as 257 | date_utc date; 258 | begin 259 | date_utc := sys_extract_utc(cast(p_date as timestamp)); 260 | return trunc((date_utc - date'1970-01-01') * 24 * 60 * 60); 261 | end get_epoch; 262 | 263 | function epoch_to_dt (p_epoch in number) return date as 264 | begin 265 | return date'1970-01-01' + (p_epoch / 24 / 60 / 60) 266 | + (systimestamp-sys_extract_utc(systimestamp)); 267 | end epoch_to_dt; 268 | 269 | procedure url_param (buf in out varchar2, attr in varchar2, val in varchar2) is 270 | begin 271 | 272 | if val is not null then 273 | if buf is not null then 274 | buf := buf || '&'; 275 | end if; 276 | buf := buf || attr || '=' || apex_util.url_encode(val); 277 | end if; 278 | 279 | end url_param; 280 | 281 | procedure url_param (buf in out varchar2, attr in varchar2, dt in date) is 282 | begin 283 | 284 | if dt is not null then 285 | if buf is not null then 286 | buf := buf || '&'; 287 | end if; 288 | buf := buf || attr || '=' || get_epoch(dt); 289 | end if; 290 | 291 | end url_param; 292 | 293 | procedure send_msg (p_payload in out nocopy t_clicksend_msg) as 294 | is_prod boolean; 295 | non_prod_recipient varchar2(255); 296 | recipient varchar2(255); 297 | payload varchar2(32767); 298 | resp_text varchar2(32767); 299 | 300 | procedure log_response is 301 | -- needs to commit the log entry independently of calling transaction 302 | pragma autonomous_transaction; 303 | log clicksend_msg_log%rowtype; 304 | begin 305 | 306 | log.sent_ts := systimestamp; 307 | log.message_type := p_payload.message_type; 308 | log.requested_ts := p_payload.requested_ts; 309 | log.schedule_dt := p_payload.schedule_dt; 310 | log.sender := p_payload.sender; 311 | log.recipient := p_payload.recipient; 312 | log.subject := p_payload.subject; 313 | log.message := p_payload.message; 314 | log.media_file := p_payload.media_file; 315 | log.voice_lang := p_payload.voice_lang; 316 | log.voice_gender := p_payload.voice_gender; 317 | log.country := p_payload.country; 318 | log.reply_email := p_payload.reply_email; 319 | log.custom_string := p_payload.custom_string; 320 | log.clicksend_response := substr(resp_text, 1, 4000); 321 | 322 | begin 323 | apex_json.parse(resp_text); 324 | 325 | log.clicksend_messageid := apex_json.get_varchar2('data.messages[1].message_id'); 326 | log.clicksend_result := apex_json.get_number('http_code'); 327 | log.clicksend_errortext := apex_json.get_varchar2('response_code'); 328 | log.clicksend_cost := apex_json.get_number('data.total_price'); 329 | exception 330 | when others then 331 | -- log the parse problem but don't stop the logging 332 | sys.dbms_output.put_line(SQLERRM); 333 | sys.dbms_output.put_line(resp_text); 334 | end; 335 | 336 | insert into clicksend_msg_log values log; 337 | 338 | commit; 339 | 340 | end log_response; 341 | 342 | begin 343 | 344 | assert(p_payload.message_type in (message_type_sms, message_type_mms, message_type_voice) 345 | ,'message_type must be sms, mms or voice'); 346 | 347 | prod_check 348 | (p_is_prod => is_prod 349 | ,p_non_prod_recipient => non_prod_recipient 350 | ); 351 | 352 | if not is_prod and non_prod_recipient is not null then 353 | 354 | -- replace recipient with the non-prod recipient 355 | recipient := non_prod_recipient; 356 | 357 | else 358 | 359 | recipient := p_payload.recipient; 360 | 361 | end if; 362 | 363 | begin 364 | apex_json.initialize_clob_output; 365 | apex_json.open_object; 366 | if p_payload.media_file is not null then 367 | apex_json.write('media_file', p_payload.media_file); 368 | end if; 369 | apex_json.open_array('messages'); 370 | apex_json.open_object; 371 | apex_json.write('source', 'oracle'); 372 | if p_payload.message_type in (message_type_sms, message_type_mms) then 373 | apex_json.write('from', p_payload.sender); 374 | end if; 375 | if p_payload.message_type = message_type_mms then 376 | apex_json.write('subject', p_payload.subject); 377 | end if; 378 | apex_json.write('body', p_payload.message); 379 | apex_json.write('to', recipient); 380 | if p_payload.message_type = message_type_voice then 381 | apex_json.write('lang', p_payload.voice_lang); 382 | apex_json.write('voice', p_payload.voice_gender); 383 | end if; 384 | if p_payload.schedule_dt is not null then 385 | apex_json.write('schedule', get_epoch(p_payload.schedule_dt)); 386 | end if; 387 | if p_payload.custom_string is not null then 388 | apex_json.write('custom_string', p_payload.custom_string); 389 | end if; 390 | if p_payload.country is not null then 391 | apex_json.write('country', p_payload.country); 392 | end if; 393 | if p_payload.reply_email is not null then 394 | apex_json.write('from_email', p_payload.reply_email); 395 | end if; 396 | apex_json.close_all; 397 | payload := apex_json.get_clob_output; 398 | apex_json.free_output; 399 | exception 400 | when others then 401 | apex_json.free_output; 402 | raise; 403 | end; 404 | 405 | if is_prod or non_prod_recipient is not null then 406 | 407 | resp_text := get_json 408 | (p_url => setting(setting_api_url) || p_payload.message_type || '/send' 409 | ,p_method => 'POST' 410 | ,p_data => payload 411 | ,p_user => setting(setting_clicksend_username) 412 | ,p_pwd => setting(setting_clicksend_secret_key) 413 | ); 414 | 415 | else 416 | 417 | resp_text := 'message suppressed: ' || sys_context('userenv','db_name'); 418 | 419 | end if; 420 | 421 | log_response; 422 | 423 | end send_msg; 424 | 425 | -- convert '0408123456' to '+61408123456' 426 | function local_to_intnl_au 427 | (p_mobile in varchar2 428 | ,p_country in varchar2 429 | ) return varchar2 is 430 | ret varchar2(20) := substr(p_mobile, 1, 20); 431 | begin 432 | 433 | if substr(ret, 1, 1) != '+' 434 | and p_country = 'AU' then 435 | ret := '+61' || substr(ret, 2); 436 | end if; 437 | 438 | return ret; 439 | end local_to_intnl_au; 440 | 441 | -- comma-delimited list of attributes, plus values if required 442 | function json_members_csv 443 | (p_path in varchar2 444 | ,p0 in varchar2 445 | ,p_values in boolean 446 | ) return varchar2 is 447 | arr wwv_flow_t_varchar2; 448 | buf varchar2(32767); 449 | begin 450 | 451 | arr := apex_json.get_members(p_path, p0); 452 | if arr.count > 0 then 453 | for i in 1..arr.count loop 454 | if buf is not null then 455 | buf := buf || ','; 456 | end if; 457 | buf := buf || arr(i); 458 | if p_values then 459 | buf := buf || '=' || apex_json.get_varchar2(p_path || '.' || arr(i), p0); 460 | end if; 461 | end loop; 462 | end if; 463 | 464 | return buf; 465 | exception 466 | when value_error /*not an array or object*/ then 467 | return null; 468 | end json_members_csv; 469 | 470 | -------------------------------------------------------------------------------- 471 | --------------------------------- PUBLIC METHODS ------------------------------ 472 | -------------------------------------------------------------------------------- 473 | 474 | procedure init 475 | (p_clicksend_username in varchar2 := default_no_change 476 | ,p_clicksend_secret_key in varchar2 := default_no_change 477 | ,p_api_url in varchar2 := default_no_change 478 | ,p_wallet_path in varchar2 := default_no_change 479 | ,p_wallet_password in varchar2 := default_no_change 480 | ,p_default_sender in varchar2 := default_no_change 481 | ,p_default_country in varchar2 := default_no_change 482 | ,p_default_voice_lang in varchar2 := default_no_change 483 | ,p_default_voice_gender in varchar2 := default_no_change 484 | ,p_voice_preamble in varchar2 := default_no_change 485 | ,p_log_retention_days in number := null 486 | ,p_queue_expiration in number := null 487 | ,p_prod_instance_name in varchar2 := default_no_change 488 | ,p_non_prod_recipient in varchar2 := default_no_change 489 | ) is 490 | begin 491 | 492 | if nvl(p_clicksend_username,'*') != default_no_change then 493 | set_setting(setting_clicksend_username, p_clicksend_username); 494 | end if; 495 | 496 | if nvl(p_clicksend_secret_key,'*') != default_no_change then 497 | set_setting(setting_clicksend_secret_key, p_clicksend_secret_key); 498 | end if; 499 | 500 | if nvl(p_api_url,'*') != default_no_change then 501 | -- make sure the url ends with a / 502 | set_setting(setting_api_url, p_api_url 503 | || case when substr(p_api_url,-1,1) != '/' then '/' end); 504 | end if; 505 | 506 | if nvl(p_wallet_path,'*') != default_no_change then 507 | set_setting(setting_wallet_path, p_wallet_path); 508 | end if; 509 | 510 | if nvl(p_wallet_password,'*') != default_no_change then 511 | set_setting(setting_wallet_password, p_wallet_password); 512 | end if; 513 | 514 | if nvl(p_default_sender,'*') != default_no_change then 515 | set_setting(setting_default_sender, p_default_sender); 516 | end if; 517 | 518 | if nvl(p_default_country,'*') != default_no_change then 519 | set_setting(setting_default_country, p_default_country); 520 | end if; 521 | 522 | if nvl(p_default_voice_lang,'*') != default_no_change then 523 | set_setting(setting_default_voice_lang, p_default_voice_lang); 524 | end if; 525 | 526 | if nvl(p_default_voice_gender,'*') != default_no_change then 527 | set_setting(setting_default_voice_gender, p_default_voice_gender); 528 | end if; 529 | 530 | if nvl(p_voice_preamble,'*') != default_no_change then 531 | set_setting(setting_voice_preamble, p_voice_preamble); 532 | end if; 533 | 534 | if p_log_retention_days is not null then 535 | set_setting(setting_log_retention_days, p_log_retention_days); 536 | end if; 537 | 538 | if p_queue_expiration is not null then 539 | set_setting(setting_queue_expiration, p_queue_expiration); 540 | end if; 541 | 542 | if nvl(p_prod_instance_name,'*') != default_no_change then 543 | set_setting(setting_prod_instance_name, p_prod_instance_name); 544 | end if; 545 | 546 | if nvl(p_non_prod_recipient,'*') != default_no_change then 547 | set_setting(setting_non_prod_recipient, p_non_prod_recipient); 548 | end if; 549 | 550 | end init; 551 | 552 | procedure send_sms 553 | (p_mobile in varchar2 554 | ,p_message in varchar2 555 | ,p_sender in varchar2 := null 556 | ,p_schedule_dt in date := null -- default is ASAP 557 | ,p_country in varchar2 := null 558 | ,p_reply_email in varchar2 := null 559 | ,p_custom_string in varchar2 := null 560 | ,p_priority in number := default_priority -- lower numbers are processed first 561 | ) is 562 | enq_opts sys.dbms_aq.enqueue_options_t; 563 | enq_msg_props sys.dbms_aq.message_properties_t; 564 | payload t_clicksend_msg; 565 | msgid raw(16); 566 | sender varchar2(100); 567 | country varchar2(10); 568 | begin 569 | 570 | reset; 571 | 572 | assert(p_mobile is not null, 'p_mobile cannot be null'); 573 | 574 | if substr(p_mobile, 1, 1) = '+' then 575 | assert(length(p_mobile) = 12, 'mobile starting with + must be 12 characters exactly (' || p_mobile || ')'); 576 | assert(replace(translate(substr(p_mobile,2),'0123456789','-'),'-','') is null, 'mobile starting with + must have 11 digits (' || p_mobile || ')'); 577 | else 578 | assert(length(p_mobile) = 10, 'mobile must have 10 digits exactly (' || p_mobile || ') (unless it starts with a +)'); 579 | assert(replace(translate(p_mobile,'0123456789','-'),'-','') is null, 'mobile must be 10 digits (' || p_mobile || ') (unless it starts with a +)'); 580 | end if; 581 | 582 | country := nvl(p_country, setting(setting_default_country)); 583 | 584 | if country = 'AU' then 585 | assert(substr(p_mobile, 1, 2) in ('04', '05') or substr(p_mobile, 1, 4) in ('+614', '+615'), 'AU mobile must start with 04 or 05 (or +614 or +615)'); 586 | end if; 587 | 588 | assert(p_message is not null, 'p_message cannot be null'); 589 | assert(length(p_message) <= 960, 'maximum message length is 960 (' || length(p_message) || ')'); 590 | 591 | sender := nvl(p_sender, setting(setting_default_sender)); 592 | assert(sender is not null, 'sender cannot be null'); 593 | assert(length(sender) <= 11, 'sender cannot be >11 characters (' || sender || ')'); 594 | 595 | assert(length(p_reply_email) <= 255, 'p_reply_email cannot be >255 characters'); 596 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 597 | 598 | payload := t_clicksend_msg 599 | (message_type => message_type_sms 600 | ,requested_ts => systimestamp 601 | ,schedule_dt => p_schedule_dt 602 | ,sender => sender 603 | ,recipient => local_to_intnl_au(p_mobile, country) 604 | ,subject => '' 605 | ,message => p_message 606 | ,media_file => '' 607 | ,voice_lang => '' 608 | ,voice_gender => '' 609 | ,country => country 610 | ,reply_email => p_reply_email 611 | ,custom_string => p_custom_string 612 | ); 613 | 614 | enq_msg_props.expiration := setting(setting_queue_expiration); 615 | enq_msg_props.priority := p_priority; 616 | 617 | sys.dbms_aq.enqueue 618 | (queue_name => queue_name 619 | ,enqueue_options => enq_opts 620 | ,message_properties => enq_msg_props 621 | ,payload => payload 622 | ,msgid => msgid 623 | ); 624 | 625 | end send_sms; 626 | 627 | procedure send_mms 628 | (p_mobile in varchar2 629 | ,p_subject in varchar2 630 | ,p_message in varchar2 631 | ,p_media_file_url in varchar2 632 | ,p_sender in varchar2 := null 633 | ,p_schedule_dt in date := null -- default is ASAP 634 | ,p_country in varchar2 := null 635 | ,p_reply_email in varchar2 := null 636 | ,p_custom_string in varchar2 := null 637 | ,p_priority in number := default_priority -- lower numbers are processed first 638 | ) is 639 | enq_opts sys.dbms_aq.enqueue_options_t; 640 | enq_msg_props sys.dbms_aq.message_properties_t; 641 | payload t_clicksend_msg; 642 | msgid raw(16); 643 | sender varchar2(100); 644 | country varchar2(10); 645 | begin 646 | 647 | reset; 648 | 649 | assert(p_mobile is not null, 'p_mobile cannot be null'); 650 | 651 | assert(p_subject is not null, 'p_subject cannot be null'); 652 | assert(length(p_subject) <= 20, 'maximum subject length is 20 (' || length(p_subject) || ')'); 653 | 654 | assert(p_media_file_url is not null, 'p_media_file_url cannot be null'); 655 | 656 | if substr(p_mobile, 1, 1) = '+' then 657 | assert(length(p_mobile) = 12, 'mobile starting with + must be 12 characters exactly (' || p_mobile || ')'); 658 | assert(replace(translate(substr(p_mobile,2),'0123456789','-'),'-','') is null, 'mobile starting with + must have 11 digits (' || p_mobile || ')'); 659 | else 660 | assert(length(p_mobile) = 10, 'mobile must have 10 digits exactly (' || p_mobile || ') (unless it starts with a +)'); 661 | assert(replace(translate(p_mobile,'0123456789','-'),'-','') is null, 'mobile must be 10 digits (' || p_mobile || ') (unless it starts with a +)'); 662 | end if; 663 | 664 | country := nvl(p_country, setting(setting_default_country)); 665 | 666 | if country = 'AU' then 667 | assert(substr(p_mobile, 1, 2) in ('04', '05') or substr(p_mobile, 1, 4) in ('+614', '+615'), 'AU mobile must start with 04 or 05 (or +614 or +615)'); 668 | end if; 669 | 670 | assert(p_message is not null, 'p_message cannot be null'); 671 | assert(length(p_message) <= 1500, 'maximum message length is 1500 (' || length(p_message) || ')'); 672 | 673 | sender := nvl(p_sender, setting(setting_default_sender)); 674 | assert(sender is not null, 'sender cannot be null'); 675 | assert(length(sender) <= 11, 'sender cannot be >11 characters (' || sender || ')'); 676 | 677 | assert(length(p_reply_email) <= 255, 'p_reply_email cannot be >255 characters'); 678 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 679 | 680 | payload := t_clicksend_msg 681 | (message_type => message_type_mms 682 | ,requested_ts => systimestamp 683 | ,schedule_dt => p_schedule_dt 684 | ,sender => sender 685 | ,recipient => local_to_intnl_au(p_mobile, country) 686 | ,subject => p_subject 687 | ,message => p_message 688 | ,media_file => p_media_file_url 689 | ,voice_lang => '' 690 | ,voice_gender => '' 691 | ,country => country 692 | ,reply_email => p_reply_email 693 | ,custom_string => p_custom_string 694 | ); 695 | 696 | enq_msg_props.expiration := setting(setting_queue_expiration); 697 | enq_msg_props.priority := p_priority; 698 | 699 | sys.dbms_aq.enqueue 700 | (queue_name => queue_name 701 | ,enqueue_options => enq_opts 702 | ,message_properties => enq_msg_props 703 | ,payload => payload 704 | ,msgid => msgid 705 | ); 706 | 707 | end send_mms; 708 | 709 | procedure send_voice 710 | (p_phone_no in varchar2 711 | ,p_message in varchar2 712 | ,p_voice_lang in varchar2 := null 713 | ,p_voice_gender in varchar2 := null 714 | ,p_schedule_dt in date := null -- default is ASAP 715 | ,p_country in varchar2 := null 716 | ,p_custom_string in varchar2 := null 717 | ,p_priority in number := default_priority -- lower numbers are processed first 718 | ) is 719 | enq_opts sys.dbms_aq.enqueue_options_t; 720 | enq_msg_props sys.dbms_aq.message_properties_t; 721 | payload t_clicksend_msg; 722 | msgid raw(16); 723 | message varchar2(4000); 724 | voice_lang varchar2(100); 725 | voice_gender varchar2(6); 726 | country varchar2(10); 727 | begin 728 | 729 | reset; 730 | 731 | assert(p_phone_no is not null, 'p_phone_no cannot be null'); 732 | 733 | if substr(p_phone_no, 1, 1) = '+' then 734 | assert(length(p_phone_no) = 12, 'phone_no starting with + must be 12 characters exactly (' || p_phone_no || ')'); 735 | assert(replace(translate(substr(p_phone_no,2),'0123456789','-'),'-','') is null, 'phone_no starting with + must have 11 digits (' || p_phone_no || ')'); 736 | else 737 | assert(length(p_phone_no) = 10, 'phone_no must have 10 digits exactly (' || p_phone_no || ') (unless it starts with a +)'); 738 | assert(replace(translate(p_phone_no,'0123456789','-'),'-','') is null, 'phone_no must be 10 digits (' || p_phone_no || ') (unless it starts with a +)'); 739 | end if; 740 | 741 | country := nvl(p_country, setting(setting_default_country)); 742 | 743 | assert(p_message is not null, 'p_message cannot be null'); 744 | message := substr(setting(setting_voice_preamble) || p_message, 1, 4000); 745 | assert(length(message) <= 1200, 'maximum message length is 1200 (' || length(message) || ') including preamble'); 746 | 747 | voice_lang := nvl(p_voice_lang, setting(setting_default_voice_lang)); 748 | assert(voice_lang is not null, 'voice_lang cannot be null'); 749 | 750 | voice_gender := nvl(p_voice_gender, setting(setting_default_voice_gender)); 751 | assert(voice_gender in ('female','male'), 'voice_gender must be female or male'); 752 | 753 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 754 | 755 | payload := t_clicksend_msg 756 | (message_type => message_type_voice 757 | ,requested_ts => systimestamp 758 | ,schedule_dt => p_schedule_dt 759 | ,sender => '' 760 | ,recipient => p_phone_no 761 | ,subject => '' 762 | ,message => message 763 | ,media_file => '' 764 | ,voice_lang => voice_lang 765 | ,voice_gender => voice_gender 766 | ,country => country 767 | ,reply_email => '' 768 | ,custom_string => p_custom_string 769 | ); 770 | 771 | enq_msg_props.expiration := setting(setting_queue_expiration); 772 | enq_msg_props.priority := p_priority; 773 | 774 | sys.dbms_aq.enqueue 775 | (queue_name => queue_name 776 | ,enqueue_options => enq_opts 777 | ,message_properties => enq_msg_props 778 | ,payload => payload 779 | ,msgid => msgid 780 | ); 781 | 782 | end send_voice; 783 | 784 | function get_account_details return varchar2 is 785 | pragma autonomous_transaction; 786 | v_json varchar2(32767); 787 | begin 788 | 789 | reset; 790 | 791 | v_json := get_json 792 | (p_url => setting(setting_api_url) || 'account' 793 | ,p_method => 'GET' 794 | ,p_user => setting(setting_clicksend_username) 795 | ,p_pwd => setting(setting_clicksend_secret_key) 796 | ,p_accept => 'application/json' 797 | ); 798 | 799 | return v_json; 800 | end get_account_details; 801 | 802 | function get_credit_balance return number is 803 | v_json varchar2(4000); 804 | v_bal varchar2(4000); 805 | begin 806 | 807 | v_json := get_account_details; 808 | 809 | apex_json.parse(v_json); 810 | 811 | v_bal := apex_json.get_varchar2('data.balance'); 812 | 813 | return to_number(v_bal); 814 | end get_credit_balance; 815 | 816 | function get_languages return t_clicksend_lang_arr pipelined is 817 | v_json varchar2(32767); 818 | data_count number; 819 | gender apex_json.t_value; 820 | gender1 varchar2(10); 821 | gender2 varchar2(10); 822 | begin 823 | 824 | v_json := get_json 825 | (p_url => setting(setting_api_url) || 'voice/lang' 826 | ,p_method => 'GET' 827 | ,p_user => setting(setting_clicksend_username) 828 | ,p_pwd => setting(setting_clicksend_secret_key) 829 | ,p_accept => 'application/json' 830 | ); 831 | 832 | apex_json.parse(v_json); 833 | 834 | data_count := apex_json.get_count('data'); 835 | 836 | if data_count > 0 then 837 | for i in 1..data_count loop 838 | 839 | gender1 := null; 840 | gender2 := null; 841 | gender := apex_json.get_value('data[%d].gender', i); 842 | 843 | -- perversely, the gender node might be a simple value (e.g. "gender":"female") 844 | -- or it might be an array (e.g. "gender":["female","male"]) 845 | if gender.kind = apex_json.c_varchar2 then 846 | gender1 := gender.varchar2_value; 847 | elsif gender.kind = apex_json.c_array then 848 | gender1 := apex_json.get_varchar2('data[%d].gender[1]', i); 849 | gender2 := apex_json.get_varchar2('data[%d].gender[2]', i); 850 | end if; 851 | 852 | pipe row (t_clicksend_lang 853 | (lang_code => substr(apex_json.get_varchar2('data[%d].code', i), 1, 10) 854 | ,country_desc => substr(apex_json.get_varchar2('data[%d].country', i), 1, 100) 855 | ,female => case when voice_female in (gender1,gender2) then 'Y' end 856 | ,male => case when voice_male in (gender1,gender2) then 'Y' end 857 | )); 858 | 859 | end loop; 860 | end if; 861 | 862 | return; 863 | end get_languages; 864 | 865 | function get_countries return t_clicksend_country_arr pipelined is 866 | v_json varchar2(32767); 867 | data_count number; 868 | begin 869 | 870 | v_json := get_json 871 | (p_url => setting(setting_api_url) || 'countries' 872 | ,p_method => 'GET' 873 | ,p_accept => 'application/json' 874 | ); 875 | 876 | apex_json.parse(v_json); 877 | 878 | data_count := apex_json.get_count('data'); 879 | 880 | if data_count > 0 then 881 | for i in 1..data_count loop 882 | 883 | pipe row (t_clicksend_country 884 | (country_code => substr(apex_json.get_varchar2('data[%d].code', i), 1, 10) 885 | ,country_name => substr(apex_json.get_varchar2('data[%d].value', i), 1, 100) 886 | )); 887 | 888 | end loop; 889 | end if; 890 | 891 | return; 892 | end get_countries; 893 | 894 | function get_sms_history 895 | (p_from in date := null -- default is 7 days prior to p_until 896 | ,p_until in date := null -- default is sysdate 897 | ) return t_clicksend_sms_history_arr pipelined is 898 | prm varchar2(4000); 899 | url varchar2(4000); 900 | v_json varchar2(32767); 901 | data_count number; 902 | page_count number := 1; 903 | begin 904 | 905 | url_param(prm, 'date_from', nvl(p_from, nvl(p_until, sysdate) - 7)); 906 | url_param(prm, 'date_to', nvl(p_until, sysdate)); 907 | 908 | v_json := get_json 909 | (p_url => setting(setting_api_url) || 'sms/history' 910 | ,p_method => 'GET' 911 | ,p_params => prm 912 | ,p_user => setting(setting_clicksend_username) 913 | ,p_pwd => setting(setting_clicksend_secret_key) 914 | ,p_accept => 'application/json' 915 | ); 916 | 917 | loop 918 | 919 | apex_json.parse(v_json); 920 | 921 | data_count := apex_json.get_count('data.data'); 922 | 923 | if data_count > 0 then 924 | for i in 1..data_count loop 925 | 926 | pipe row (t_clicksend_sms_history 927 | (event_dt => epoch_to_dt(apex_json.get_varchar2('data.data[%d].date', i)) 928 | ,mobile => substr(apex_json.get_varchar2('data.data[%d].to', i), 1, 20) 929 | ,message => substr(apex_json.get_varchar2('data.data[%d].body', i), 1, 4000) 930 | ,status => substr(apex_json.get_varchar2('data.data[%d].status', i), 1, 100) 931 | ,sender => substr(apex_json.get_varchar2('data.data[%d].from', i), 1, 100) 932 | ,schedule_dt => epoch_to_dt(apex_json.get_varchar2('data.data[%d].schedule', i)) 933 | ,status_code => substr(apex_json.get_varchar2('data.data[%d].status_code', i), 1, 100) 934 | ,status_text => substr(apex_json.get_varchar2('data.data[%d].status_text', i), 1, 4000) 935 | ,error_code => substr(apex_json.get_varchar2('data.data[%d].error_code', i), 1, 100) 936 | ,error_text => substr(apex_json.get_varchar2('data.data[%d].error_text', i), 1, 4000) 937 | ,message_id => substr(apex_json.get_varchar2('data.data[%d].message_id', i), 1, 4000) 938 | ,message_parts => to_number(apex_json.get_varchar2('data.data[%d].message_parts', i)) 939 | ,message_price => to_number(apex_json.get_varchar2('data.data[%d].message_price', i)) 940 | ,reply_email => substr(apex_json.get_varchar2('data.data[%d].from_email', i), 1, 255) 941 | ,custom_string => substr(apex_json.get_varchar2('data.data[%d].custom_string', i), 1, 4000) 942 | ,subaccount_id => apex_json.get_number('data.data[%d].subaccount_id', i) 943 | ,country => substr(apex_json.get_varchar2('data.data[%d].country', i), 1, 10) 944 | ,carrier => substr(apex_json.get_varchar2('data.data[%d].carrier', i), 1, 100) 945 | )); 946 | 947 | end loop; 948 | end if; 949 | 950 | url := apex_json.get_varchar2('data.next_page_url'); 951 | 952 | exit when url is null; 953 | 954 | v_json := get_json 955 | (p_url => setting(setting_api_url) || 'sms/history' || url 956 | ,p_method => 'GET' 957 | ,p_user => setting(setting_clicksend_username) 958 | ,p_pwd => setting(setting_clicksend_secret_key) 959 | ,p_accept => 'application/json' 960 | ); 961 | 962 | page_count := page_count + 1; 963 | 964 | exit when page_count > 10; 965 | 966 | end loop; 967 | 968 | return; 969 | end get_sms_history; 970 | 971 | procedure create_queue 972 | (p_max_retries in number := default_max_retries 973 | ,p_retry_delay in number := default_retry_delay 974 | ) is 975 | begin 976 | 977 | sys.dbms_aqadm.create_queue_table 978 | (queue_table => queue_table 979 | ,queue_payload_type => payload_type 980 | ,sort_list => 'priority,enq_time' 981 | ); 982 | 983 | sys.dbms_aqadm.create_queue 984 | (queue_name => queue_name 985 | ,queue_table => queue_table 986 | ,max_retries => p_max_retries 987 | ,retry_delay => p_retry_delay 988 | ); 989 | 990 | sys.dbms_aqadm.start_queue (queue_name); 991 | 992 | end create_queue; 993 | 994 | procedure drop_queue is 995 | begin 996 | 997 | sys.dbms_aqadm.stop_queue (queue_name); 998 | 999 | sys.dbms_aqadm.drop_queue (queue_name); 1000 | 1001 | sys.dbms_aqadm.drop_queue_table (queue_table); 1002 | 1003 | end drop_queue; 1004 | 1005 | procedure purge_queue (p_msg_state IN VARCHAR2 := default_purge_msg_state) is 1006 | r_opt sys.dbms_aqadm.aq$_purge_options_t; 1007 | begin 1008 | 1009 | sys.dbms_aqadm.purge_queue_table 1010 | (queue_table => queue_table 1011 | ,purge_condition => case when p_msg_state is not null 1012 | then replace(q'[ qtview.msg_state = '#STATE#' ]' 1013 | ,'#STATE#', p_msg_state) 1014 | end 1015 | ,purge_options => r_opt); 1016 | 1017 | end purge_queue; 1018 | 1019 | procedure push_queue 1020 | (p_asynchronous in boolean := false) as 1021 | r_dequeue_options sys.dbms_aq.dequeue_options_t; 1022 | r_message_properties sys.dbms_aq.message_properties_t; 1023 | msgid raw(16); 1024 | payload t_clicksend_msg; 1025 | dequeue_count integer := 0; 1026 | job binary_integer; 1027 | begin 1028 | 1029 | if p_asynchronous then 1030 | 1031 | -- use dbms_job so that it is only run if/when this session commits 1032 | 1033 | sys.dbms_job.submit 1034 | (job => job 1035 | ,what => $$plsql_unit || '.push_queue;' 1036 | ); 1037 | 1038 | else 1039 | 1040 | reset; 1041 | 1042 | -- commit any messages requested in the current session 1043 | commit; 1044 | 1045 | r_dequeue_options.wait := sys.dbms_aq.no_wait; 1046 | 1047 | -- loop through all messages in the queue until there is none 1048 | -- exit this loop when the e_no_queue_data exception is raised. 1049 | loop 1050 | 1051 | sys.dbms_aq.dequeue 1052 | (queue_name => queue_name 1053 | ,dequeue_options => r_dequeue_options 1054 | ,message_properties => r_message_properties 1055 | ,payload => payload 1056 | ,msgid => msgid 1057 | ); 1058 | 1059 | 1060 | -- process the message 1061 | send_msg (p_payload => payload); 1062 | 1063 | commit; -- the queue will treat the message as succeeded 1064 | 1065 | -- don't bite off everything in one go 1066 | dequeue_count := dequeue_count + 1; 1067 | exit when dequeue_count >= max_dequeue_count; 1068 | end loop; 1069 | 1070 | end if; 1071 | 1072 | exception 1073 | when e_no_queue_data then 1074 | null; 1075 | end push_queue; 1076 | 1077 | procedure create_job 1078 | (p_repeat_interval in varchar2 := default_repeat_interval) is 1079 | begin 1080 | 1081 | assert(p_repeat_interval is not null, 'create_job: p_repeat_interval cannot be null'); 1082 | 1083 | sys.dbms_scheduler.create_job 1084 | (job_name => job_name 1085 | ,job_type => 'stored_procedure' 1086 | ,job_action => $$plsql_unit||'.push_queue' 1087 | ,start_date => systimestamp 1088 | ,repeat_interval => p_repeat_interval 1089 | ); 1090 | 1091 | sys.dbms_scheduler.set_attribute(job_name,'restartable',true); 1092 | 1093 | sys.dbms_scheduler.enable(job_name); 1094 | 1095 | end create_job; 1096 | 1097 | procedure drop_job is 1098 | begin 1099 | 1100 | begin 1101 | sys.dbms_scheduler.stop_job (job_name); 1102 | exception 1103 | when others then 1104 | if sqlcode != -27366 /*job already stopped*/ then 1105 | raise; 1106 | end if; 1107 | end; 1108 | 1109 | sys.dbms_scheduler.drop_job (job_name); 1110 | 1111 | end drop_job; 1112 | 1113 | procedure purge_logs (p_log_retention_days in number := null) is 1114 | l_log_retention_days number; 1115 | begin 1116 | 1117 | reset; 1118 | 1119 | l_log_retention_days := nvl(p_log_retention_days, log_retention_days); 1120 | 1121 | delete clicksend_msg_log 1122 | where requested_ts < sysdate - l_log_retention_days; 1123 | 1124 | commit; 1125 | 1126 | end purge_logs; 1127 | 1128 | procedure create_purge_job 1129 | (p_repeat_interval in varchar2 := default_purge_repeat_interval) is 1130 | begin 1131 | 1132 | assert(p_repeat_interval is not null, 'create_purge_job: p_repeat_interval cannot be null'); 1133 | 1134 | sys.dbms_scheduler.create_job 1135 | (job_name => purge_job_name 1136 | ,job_type => 'stored_procedure' 1137 | ,job_action => $$plsql_unit||'.purge_logs' 1138 | ,start_date => systimestamp 1139 | ,repeat_interval => p_repeat_interval 1140 | ); 1141 | 1142 | sys.dbms_scheduler.set_attribute(job_name,'restartable',true); 1143 | 1144 | sys.dbms_scheduler.enable(purge_job_name); 1145 | 1146 | end create_purge_job; 1147 | 1148 | procedure drop_purge_job is 1149 | begin 1150 | 1151 | begin 1152 | sys.dbms_scheduler.stop_job (purge_job_name); 1153 | exception 1154 | when others then 1155 | if sqlcode != -27366 /*job already stopped*/ then 1156 | raise; 1157 | end if; 1158 | end; 1159 | 1160 | sys.dbms_scheduler.drop_job (purge_job_name); 1161 | 1162 | end drop_purge_job; 1163 | 1164 | procedure send_test_sms 1165 | (p_mobile in varchar2 1166 | ,p_message in varchar2 := null 1167 | ,p_sender in varchar2 := null 1168 | ,p_clicksend_username in varchar2 := default_no_change 1169 | ,p_clicksend_secret_key in varchar2 := default_no_change 1170 | ,p_api_url in varchar2 := default_no_change 1171 | ,p_wallet_path in varchar2 := default_no_change 1172 | ,p_wallet_password in varchar2 := default_no_change 1173 | ) is 1174 | payload t_clicksend_msg; 1175 | begin 1176 | 1177 | -- set up settings just for this call 1178 | load_settings; 1179 | if p_clicksend_username != default_no_change then 1180 | g_setting(setting_clicksend_username) := p_clicksend_username; 1181 | end if; 1182 | if p_clicksend_secret_key != default_no_change then 1183 | g_setting(setting_clicksend_secret_key) := p_clicksend_secret_key; 1184 | end if; 1185 | if p_api_url != default_no_change then 1186 | g_setting(setting_api_url) := p_api_url; 1187 | end if; 1188 | if p_wallet_path != default_no_change then 1189 | g_setting(setting_wallet_path) := p_wallet_path; 1190 | end if; 1191 | if p_wallet_password != default_no_change then 1192 | g_setting(setting_wallet_password) := p_wallet_password; 1193 | end if; 1194 | 1195 | payload := t_clicksend_msg 1196 | (message_type => message_type_sms 1197 | ,requested_ts => systimestamp 1198 | ,schedule_dt => null 1199 | ,sender => nvl(p_sender, setting(setting_default_sender)) 1200 | ,recipient => local_to_intnl_au(p_mobile, setting(setting_default_country)) 1201 | ,subject => '' 1202 | ,message => nvl(p_message 1203 | ,'This test message was sent from ' 1204 | || sys_context('userenv','db_name') 1205 | || ' at ' 1206 | || to_char(systimestamp,'DD/MM/YYYY HH24:MI:SS.FF')) 1207 | ,media_file => '' 1208 | ,voice_lang => '' 1209 | ,voice_gender => '' 1210 | ,country => setting(setting_default_country) 1211 | ,reply_email => '' 1212 | ,custom_string => '' 1213 | ); 1214 | 1215 | send_msg(p_payload => payload); 1216 | 1217 | -- reset everything back to normal 1218 | reset; 1219 | 1220 | exception 1221 | when others then 1222 | reset; 1223 | raise; 1224 | end send_test_sms; 1225 | 1226 | end clicksend_pkg; 1227 | / 1228 | 1229 | show errors 1230 | -------------------------------------------------------------------------------- /clicksend_pkg.pks: -------------------------------------------------------------------------------- 1 | create or replace package clicksend_pkg as 2 | /* Clicksend API v0.2 3 | https://github.com/jeffreykemp/clicksend-plsql-api 4 | by Jeffrey Kemp 5 | */ 6 | 7 | default_no_change constant varchar2(4000) := '*NO-CHANGE*'; 8 | default_priority constant number := 3; 9 | default_repeat_interval constant varchar2(200) := 'FREQ=MINUTELY;INTERVAL=5;'; 10 | default_purge_repeat_interval constant varchar2(200) := 'FREQ=WEEKLY;BYDAY=SUN;BYHOUR=0;'; 11 | default_purge_msg_state constant varchar2(100) := 'EXPIRED'; 12 | default_max_retries constant number := 10; --allow failures before giving up on a message 13 | default_retry_delay constant number := 60; --wait seconds before trying this message again 14 | 15 | -- country (note: this list is not complete) 16 | country_afghanistan constant varchar2(2) := 'AF'; 17 | country_australia constant varchar2(2) := 'AU'; 18 | country_finland constant varchar2(2) := 'FI'; 19 | country_france constant varchar2(2) := 'FR'; 20 | country_united_arab_emirates constant varchar2(2) := 'AE'; 21 | country_united_kingdom constant varchar2(2) := 'GB'; 22 | country_usa constant varchar2(2) := 'US'; 23 | country_zimbabwe constant varchar2(2) := 'ZW'; 24 | -- refer http://docs.clicksend.apiary.io/#reference/countries/country-collection/get-all-countries 25 | 26 | -- voice language (note: this list might be incomplete) 27 | voice_american constant varchar2(10) := 'en-us'; -- male or female 28 | voice_australian constant varchar2(10) := 'en-au'; -- male or female 29 | voice_british constant varchar2(10) := 'en-gb'; -- male or female 30 | voice_french constant varchar2(10) := 'fr-fr'; -- male or female 31 | voice_canadian_french constant varchar2(10) := 'fr-ca'; -- female only 32 | voice_chinese constant varchar2(10) := 'zh-cn'; -- male or female 33 | voice_dutch constant varchar2(10) := 'nl-nl'; -- male or female 34 | voice_german constant varchar2(10) := 'de-de'; -- male or female 35 | voice_indian_english constant varchar2(10) := 'en-in'; -- female only 36 | voice_icelandic constant varchar2(10) := 'is-is'; -- male or female 37 | voice_italian constant varchar2(10) := 'it-it'; -- male or female 38 | voice_japanese constant varchar2(10) := 'ja-jp'; -- male or female 39 | voice_korean constant varchar2(10) := 'ko-kr'; -- male or female 40 | voice_mexican constant varchar2(10) := 'es-mx'; -- female only 41 | voice_polish constant varchar2(10) := 'pl-pl'; -- male or female 42 | voice_portuguese constant varchar2(10) := 'pt-br'; -- male or female 43 | voice_romanian constant varchar2(10) := 'ro-ro'; -- female only 44 | voice_russian constant varchar2(10) := 'ru-ru'; -- female only 45 | voice_spanish constant varchar2(10) := 'es-es'; -- male or female 46 | voice_spanish_us constant varchar2(10) := 'es-us'; -- male or female 47 | voice_swedish constant varchar2(10) := 'sv-se'; -- female only 48 | voice_turkish constant varchar2(10) := 'tr-tr'; -- female only 49 | -- refer http://docs.clicksend.apiary.io/#reference/voice/voice-languages/voice-languages 50 | 51 | -- voice gender 52 | voice_female constant varchar2(10) := 'female'; 53 | voice_male constant varchar2(10) := 'male'; 54 | 55 | -- init: set up clicksend parameters 56 | -- default is to not change the given parameter 57 | procedure init 58 | (p_clicksend_username in varchar2 := default_no_change 59 | ,p_clicksend_secret_key in varchar2 := default_no_change 60 | ,p_api_url in varchar2 := default_no_change 61 | ,p_wallet_path in varchar2 := default_no_change 62 | ,p_wallet_password in varchar2 := default_no_change 63 | ,p_default_sender in varchar2 := default_no_change 64 | ,p_default_country in varchar2 := default_no_change 65 | ,p_default_voice_lang in varchar2 := default_no_change 66 | ,p_default_voice_gender in varchar2 := default_no_change 67 | ,p_voice_preamble in varchar2 := default_no_change 68 | ,p_log_retention_days in number := null 69 | ,p_queue_expiration in number := null 70 | ,p_prod_instance_name in varchar2 := default_no_change 71 | ,p_non_prod_recipient in varchar2 := default_no_change 72 | ); 73 | 74 | procedure send_sms 75 | (p_mobile in varchar2 76 | ,p_message in varchar2 77 | ,p_sender in varchar2 := null 78 | ,p_schedule_dt in date := null -- default is ASAP 79 | ,p_country in varchar2 := null 80 | ,p_reply_email in varchar2 := null 81 | ,p_custom_string in varchar2 := null 82 | ,p_priority in number := default_priority -- lower numbers are processed first 83 | ); 84 | 85 | procedure send_mms 86 | (p_mobile in varchar2 87 | ,p_subject in varchar2 88 | ,p_message in varchar2 89 | ,p_media_file_url in varchar2 -- must be a jpg or gif, up to 250kB, anything else must be converted first; some devices only accept up to 30kB 90 | ,p_sender in varchar2 := null 91 | ,p_schedule_dt in date := null -- default is ASAP 92 | ,p_country in varchar2 := null 93 | ,p_reply_email in varchar2 := null 94 | ,p_custom_string in varchar2 := null 95 | ,p_priority in number := default_priority -- lower numbers are processed first 96 | ); 97 | 98 | procedure send_voice 99 | (p_phone_no in varchar2 100 | ,p_message in varchar2 101 | ,p_voice_lang in varchar2 := null 102 | ,p_voice_gender in varchar2 := null 103 | ,p_schedule_dt in date := null -- default is ASAP 104 | ,p_country in varchar2 := null 105 | ,p_custom_string in varchar2 := null 106 | ,p_priority in number := default_priority -- lower numbers are processed first 107 | ); 108 | 109 | function get_account_details return varchar2; 110 | 111 | function get_credit_balance return number; 112 | 113 | function get_languages return t_clicksend_lang_arr pipelined; 114 | 115 | function get_countries return t_clicksend_country_arr pipelined; 116 | 117 | function get_sms_history 118 | (p_from in date := null -- default is 7 days ago 119 | ,p_until in date := null -- default is sysdate 120 | ) return t_clicksend_sms_history_arr pipelined; 121 | 122 | -- create the queue for asynchronous sms's 123 | procedure create_queue 124 | (p_max_retries in number := default_max_retries 125 | ,p_retry_delay in number := default_retry_delay 126 | ); 127 | 128 | -- drop the queue 129 | procedure drop_queue; 130 | 131 | -- purge any expired (failed) emails stuck in the queue 132 | procedure purge_queue (p_msg_state in varchar2 := default_purge_msg_state); 133 | 134 | -- send emails in the queue 135 | procedure push_queue 136 | (p_asynchronous in boolean := false); 137 | 138 | -- create a job to periodically call push_queue 139 | procedure create_job 140 | (p_repeat_interval in varchar2 := default_repeat_interval); 141 | 142 | -- drop the push_queue job 143 | procedure drop_job; 144 | 145 | -- purge the logs older than the given number of days 146 | procedure purge_logs (p_log_retention_days in number := null); 147 | 148 | -- create a job to periodically call purge_logs 149 | procedure create_purge_job 150 | (p_repeat_interval in varchar2 := default_purge_repeat_interval); 151 | 152 | -- drop the purge_logs job 153 | procedure drop_purge_job; 154 | 155 | -- Send a test sms. 156 | -- Can be used to test a setting without storing it. 157 | -- Bypasses the queue. 158 | procedure send_test_sms 159 | (p_mobile in varchar2 160 | ,p_message in varchar2 := null 161 | ,p_sender in varchar2 := null 162 | ,p_clicksend_username in varchar2 := default_no_change 163 | ,p_clicksend_secret_key in varchar2 := default_no_change 164 | ,p_api_url in varchar2 := default_no_change 165 | ,p_wallet_path in varchar2 := default_no_change 166 | ,p_wallet_password in varchar2 := default_no_change 167 | ); 168 | 169 | end clicksend_pkg; 170 | / 171 | 172 | show errors -------------------------------------------------------------------------------- /clicksend_pkg_with_logger.pkb: -------------------------------------------------------------------------------- 1 | create or replace package body clicksend_pkg as 2 | /* Clicksend API v0.3 3 | https://github.com/jeffreykemp/clicksend-plsql-api 4 | by Jeffrey Kemp 5 | Instrumented using Logger https://github.com/OraOpenSource/Logger 6 | */ 7 | 8 | scope_prefix constant varchar2(31) := lower($$plsql_unit) || '.'; 9 | 10 | queue_name constant varchar2(500) := sys_context('userenv','current_schema')||'.clicksend_queue'; 11 | queue_table constant varchar2(500) := sys_context('userenv','current_schema')||'.clicksend_queue_tab'; 12 | job_name constant varchar2(30) := 'clicksend_process_queue'; 13 | purge_job_name constant varchar2(30) := 'clicksend_purge_logs'; 14 | payload_type constant varchar2(500) := sys_context('userenv','current_schema')||'.t_clicksend_msg'; 15 | max_dequeue_count constant integer := 1000; -- max messages processed by push_queue in one go 16 | 17 | -- defaults to use if init() not used to set these settings 18 | default_country constant varchar2(10) := 'AU'; 19 | default_api_url constant varchar2(200) := 'https://rest.clicksend.com/v3/'; 20 | default_voice_lang constant varchar2(10) := 'en-au'; -- aussie 21 | default_voice_gender constant varchar2(6) := 'female'; 22 | default_voice_preamble constant varchar2(500) := '.....'; -- add a pause at the start 23 | default_log_retention_days constant number := 30; 24 | default_queue_expiration constant integer := 24 * 60 * 60; -- failed messages expire from the queue after 24 hours 25 | 26 | -- message types 27 | message_type_sms constant varchar2(20) := 'sms'; 28 | message_type_mms constant varchar2(20) := 'mms'; 29 | message_type_voice constant varchar2(20) := 'voice'; 30 | 31 | -- setting names 32 | setting_clicksend_username constant varchar2(100) := 'clicksend_username'; 33 | setting_clicksend_secret_key constant varchar2(100) := 'clicksend_secret_key'; 34 | setting_api_url constant varchar2(100) := 'api_url'; 35 | setting_wallet_path constant varchar2(100) := 'wallet_path'; 36 | setting_wallet_password constant varchar2(100) := 'wallet_password'; 37 | setting_log_retention_days constant varchar2(100) := 'log_retention_days'; 38 | setting_default_sender constant varchar2(100) := 'default_sender'; 39 | setting_default_country constant varchar2(100) := 'default_country'; 40 | setting_default_voice_lang constant varchar2(100) := 'default_voice_lang'; 41 | setting_default_voice_gender constant varchar2(100) := 'default_voice_gender'; 42 | setting_voice_preamble constant varchar2(100) := 'voice_preamble'; 43 | setting_queue_expiration constant varchar2(100) := 'queue_expiration'; 44 | setting_prod_instance_name constant varchar2(100) := 'prod_instance_name'; 45 | setting_non_prod_recipient constant varchar2(100) := 'non_prod_recipient'; 46 | 47 | type t_key_val_arr is table of varchar2(4000) index by varchar2(100); 48 | 49 | g_setting t_key_val_arr; 50 | 51 | e_no_queue_data exception; 52 | pragma exception_init (e_no_queue_data, -25228); 53 | 54 | -------------------------------------------------------------------------------- 55 | --------------------------------- PRIVATE METHODS ------------------------------ 56 | -------------------------------------------------------------------------------- 57 | 58 | procedure assert (cond in boolean, err in varchar2) is 59 | begin 60 | if not cond then 61 | raise_application_error(-20000, $$plsql_unit || ' assertion failed: ' || err); 62 | end if; 63 | end assert; 64 | 65 | -- set or update a setting 66 | procedure set_setting 67 | (p_name in varchar2 68 | ,p_value in varchar2 69 | ) is 70 | scope logger_logs.scope%type := scope_prefix || 'set_setting'; 71 | params logger.tab_param; 72 | begin 73 | logger.append_param(params,'p_name',p_name); 74 | logger.append_param(params,'p_value',case when p_value is null then 'null' else 'not null' end); 75 | logger.log('START', scope, null, params); 76 | 77 | assert(p_name is not null, 'p_name cannot be null'); 78 | 79 | merge into clicksend_settings t 80 | using (select p_name as setting_name 81 | ,p_value as setting_value 82 | from dual) s 83 | on (t.setting_name = s.setting_name) 84 | when matched then 85 | update set t.setting_value = s.setting_value 86 | when not matched then 87 | insert (setting_name, setting_value) 88 | values (s.setting_name, s.setting_value); 89 | 90 | logger.log('MERGE clicksend_settings: ' || SQL%ROWCOUNT, scope, null, params); 91 | 92 | logger.log('commit', scope, null, params); 93 | commit; 94 | 95 | logger.log('END', scope, null, params); 96 | exception 97 | when others then 98 | logger.log_error('Unhandled Exception', scope, null, params); 99 | raise; 100 | end set_setting; 101 | 102 | -- retrieve all the settings for a normal session 103 | procedure load_settings is 104 | scope logger_logs.scope%type := scope_prefix || 'load_settings'; 105 | params logger.tab_param; 106 | begin 107 | logger.log('START', scope, null, params); 108 | 109 | -- set defaults first 110 | g_setting(setting_api_url) := default_api_url; 111 | g_setting(setting_wallet_path) := ''; 112 | g_setting(setting_wallet_password) := ''; 113 | g_setting(setting_log_retention_days) := default_log_retention_days; 114 | g_setting(setting_default_sender) := ''; 115 | g_setting(setting_default_country) := default_country; 116 | g_setting(setting_default_voice_lang) := default_voice_lang; 117 | g_setting(setting_default_voice_gender) := default_voice_gender; 118 | g_setting(setting_voice_preamble) := default_voice_preamble; 119 | g_setting(setting_queue_expiration) := default_queue_expiration; 120 | g_setting(setting_prod_instance_name) := ''; 121 | g_setting(setting_non_prod_recipient) := ''; 122 | 123 | for r in ( 124 | select s.setting_name 125 | ,s.setting_value 126 | from clicksend_settings s 127 | ) loop 128 | 129 | g_setting(r.setting_name) := r.setting_value; 130 | 131 | end loop; 132 | 133 | logger.log('END', scope, null, params); 134 | exception 135 | when others then 136 | logger.log_error('Unhandled Exception', scope, null, params); 137 | raise; 138 | end load_settings; 139 | 140 | procedure reset is 141 | scope logger_logs.scope%type := scope_prefix || 'setting'; 142 | params logger.tab_param; 143 | begin 144 | logger.log('START', scope, null, params); 145 | 146 | g_setting.delete; 147 | 148 | logger.log('END', scope, null, params); 149 | exception 150 | when others then 151 | logger.log_error('Unhandled Exception', scope, null, params); 152 | raise; 153 | end reset; 154 | 155 | -- get a setting 156 | -- if p_default is set, a null/not found will return the default value 157 | -- if p_default is null, a not found will raise an exception 158 | function setting (p_name in varchar2) return varchar2 is 159 | scope logger_logs.scope%type := scope_prefix || 'setting'; 160 | params logger.tab_param; 161 | p_value clicksend_settings.setting_value%type; 162 | begin 163 | logger.append_param(params,'p_name',p_name); 164 | logger.log('START', scope, null, params); 165 | 166 | assert(p_name is not null, 'p_name cannot be null'); 167 | 168 | -- prime the settings array for this session 169 | if g_setting.count = 0 then 170 | load_settings; 171 | end if; 172 | 173 | p_value := g_setting(p_name); 174 | 175 | logger.log('END', scope, null, params); 176 | return p_value; 177 | exception 178 | when no_data_found then 179 | logger.log_error('No Data Found', scope, null, params); 180 | raise_application_error(-20000, 'clicksend setting not set "' || p_name || '" - please setup using ' || $$plsql_unit || '.init()'); 181 | when others then 182 | logger.log_error('Unhandled Exception', scope, null, params); 183 | raise; 184 | end setting; 185 | 186 | function log_retention_days return number is 187 | begin 188 | return to_number(setting(setting_log_retention_days)); 189 | end log_retention_days; 190 | 191 | procedure prod_check 192 | (p_is_prod out boolean 193 | ,p_non_prod_recipient out varchar2 194 | ) is 195 | scope logger_logs.scope%type := scope_prefix || 'prod_check'; 196 | params logger.tab_param; 197 | prod_instance_name clicksend_settings.setting_value%type; 198 | begin 199 | logger.log('START', scope, null, params); 200 | 201 | prod_instance_name := setting(setting_prod_instance_name); 202 | 203 | if prod_instance_name is not null then 204 | p_is_prod := (prod_instance_name = sys_context('userenv','db_name')); 205 | else 206 | p_is_prod := true; -- if setting not set, we treat this as a prod env 207 | end if; 208 | 209 | if not p_is_prod then 210 | p_non_prod_recipient := setting(setting_non_prod_recipient); 211 | end if; 212 | 213 | logger.log('END', scope, null, params); 214 | exception 215 | when others then 216 | logger.log_error('Unhandled Exception', scope, null, params); 217 | raise; 218 | end prod_check; 219 | 220 | procedure log_headers (resp in out nocopy sys.utl_http.resp) is 221 | scope logger_logs.scope%type := scope_prefix || 'log_headers'; 222 | params logger.tab_param; 223 | name varchar2(256); 224 | value varchar2(1024); 225 | begin 226 | logger.log('START', scope, null, params); 227 | 228 | for i in 1..sys.utl_http.get_header_count(resp) loop 229 | sys.utl_http.get_header(resp, i, name, value); 230 | logger.log(name || ': ' || value, scope, null, params); 231 | end loop; 232 | 233 | logger.log('END', scope, null, params); 234 | exception 235 | when others then 236 | logger.log_error('Unhandled Exception', scope, null, params); 237 | raise; 238 | end log_headers; 239 | 240 | procedure set_wallet is 241 | scope logger_logs.scope%type := scope_prefix || 'set_wallet'; 242 | params logger.tab_param; 243 | wallet_path varchar2(4000); 244 | wallet_password varchar2(4000); 245 | begin 246 | logger.log('START', scope, null, params); 247 | 248 | wallet_path := setting(setting_wallet_path); 249 | wallet_password := setting(setting_wallet_password); 250 | 251 | if wallet_path is not null or wallet_password is not null then 252 | sys.utl_http.set_wallet(wallet_path, wallet_password); 253 | end if; 254 | 255 | logger.log('END', scope, null, params); 256 | exception 257 | when others then 258 | logger.log_error('Unhandled Exception', scope, null, params); 259 | raise; 260 | end set_wallet; 261 | 262 | function get_response (resp in out nocopy sys.utl_http.resp) return clob is 263 | scope logger_logs.scope%type := scope_prefix || 'get_response'; 264 | params logger.tab_param; 265 | buf varchar2(32767); 266 | ret clob := empty_clob; 267 | begin 268 | logger.log('START', scope, null, params); 269 | 270 | sys.dbms_lob.createtemporary(ret, true); 271 | 272 | begin 273 | loop 274 | sys.utl_http.read_text(resp, buf, 32767); 275 | sys.dbms_lob.writeappend(ret, length(buf), buf); 276 | end loop; 277 | exception 278 | when sys.utl_http.end_of_body then 279 | null; 280 | end; 281 | sys.utl_http.end_response(resp); 282 | 283 | logger.log('END', scope, ret, params); 284 | return ret; 285 | exception 286 | when others then 287 | logger.log_error('Unhandled Exception', scope, null, params); 288 | raise; 289 | end get_response; 290 | 291 | function get_json 292 | (p_url in varchar2 293 | ,p_method in varchar2 294 | ,p_params in varchar2 := null 295 | ,p_data in varchar2 := null 296 | ,p_user in varchar2 := null 297 | ,p_pwd in varchar2 := null 298 | ,p_accept in varchar2 := null 299 | ) return clob is 300 | scope logger_logs.scope%type := scope_prefix || 'get_json'; 301 | params logger.tab_param; 302 | url varchar2(4000) := p_url; 303 | req sys.utl_http.req; 304 | resp sys.utl_http.resp; 305 | ret clob; 306 | begin 307 | logger.append_param(params,'p_url',p_url); 308 | logger.append_param(params,'p_method',p_method); 309 | logger.append_param(params,'p_data',p_data); 310 | logger.append_param(params,'p_user',p_user); 311 | logger.append_param(params,'p_pwd',CASE WHEN p_pwd IS NOT NULL THEN '(not null)' ELSE 'NULL' END); 312 | logger.append_param(params,'p_accept',p_accept); 313 | logger.log('START', scope, null, params); 314 | 315 | assert(p_url is not null, 'get_json: p_url cannot be null'); 316 | 317 | set_wallet; 318 | 319 | if p_params is not null then 320 | url := url || '?' || p_params; 321 | end if; 322 | 323 | req := sys.utl_http.begin_request(url => url, method => p_method); 324 | 325 | if p_user is not null or p_pwd is not null then 326 | logger.log('sys.utl_http.set_authentication', scope, null, params); 327 | sys.utl_http.set_authentication(req, p_user, p_pwd); 328 | end if; 329 | 330 | if p_data is not null then 331 | logger.log('sys.utl_http set headers Content-Type/Length', scope, null, params); 332 | sys.utl_http.set_header (req,'Content-Type','application/json'); 333 | sys.utl_http.set_header (req,'Content-Length',length(p_data)); 334 | logger.log('sys.utl_http.write_text', scope, null, params); 335 | sys.utl_http.write_text (req,p_data); 336 | end if; 337 | 338 | if p_accept is not null then 339 | sys.utl_http.set_header (req,'Accept',p_accept); 340 | end if; 341 | 342 | resp := sys.utl_http.get_response(req); 343 | logger.log('HTTP response: ' || resp.status_code || ' ' || resp.reason_phrase, scope, null, params); 344 | 345 | log_headers(resp); 346 | 347 | if resp.status_code != '200' then 348 | raise_application_error(-20000, 'get_json call failed ' || resp.status_code || ' ' || resp.reason_phrase || ' [' || url || ']'); 349 | end if; 350 | 351 | ret := get_response(resp); 352 | 353 | logger.log('END', scope, ret, params); 354 | return ret; 355 | exception 356 | when others then 357 | logger.log_error('Unhandled Exception', scope, null, params); 358 | raise; 359 | end get_json; 360 | 361 | function get_epoch (p_date in date) return number as 362 | date_utc date; 363 | begin 364 | date_utc := sys_extract_utc(cast(p_date as timestamp)); 365 | return trunc((date_utc - date'1970-01-01') * 24 * 60 * 60); 366 | end get_epoch; 367 | 368 | function epoch_to_dt (p_epoch in number) return date as 369 | begin 370 | return date'1970-01-01' + (p_epoch / 24 / 60 / 60) 371 | + (systimestamp-sys_extract_utc(systimestamp)); 372 | end epoch_to_dt; 373 | 374 | procedure url_param (buf in out varchar2, attr in varchar2, val in varchar2) is 375 | scope logger_logs.scope%type := scope_prefix || 'url_param(1)'; 376 | params logger.tab_param; 377 | begin 378 | logger.append_param(params,'attr',attr); 379 | logger.append_param(params,'val',val); 380 | logger.log('START', scope, null, params); 381 | 382 | if val is not null then 383 | if buf is not null then 384 | buf := buf || '&'; 385 | end if; 386 | buf := buf || attr || '=' || apex_util.url_encode(val); 387 | end if; 388 | 389 | logger.log('END', scope, null, params); 390 | exception 391 | when others then 392 | logger.log_error('Unhandled Exception', scope, null, params); 393 | raise; 394 | end url_param; 395 | 396 | procedure url_param (buf in out varchar2, attr in varchar2, dt in date) is 397 | scope logger_logs.scope%type := scope_prefix || 'url_param(2)'; 398 | params logger.tab_param; 399 | begin 400 | logger.append_param(params,'attr',attr); 401 | logger.append_param(params,'dt',dt); 402 | logger.log('START', scope, null, params); 403 | 404 | if dt is not null then 405 | if buf is not null then 406 | buf := buf || '&'; 407 | end if; 408 | buf := buf || attr || '=' || get_epoch(dt); 409 | end if; 410 | 411 | logger.log('END', scope, null, params); 412 | exception 413 | when others then 414 | logger.log_error('Unhandled Exception', scope, null, params); 415 | raise; 416 | end url_param; 417 | 418 | procedure send_msg (p_payload in out nocopy t_clicksend_msg) as 419 | scope logger_logs.scope%type := scope_prefix || 'send_msg'; 420 | params logger.tab_param; 421 | is_prod boolean; 422 | non_prod_recipient varchar2(255); 423 | recipient varchar2(255); 424 | payload varchar2(32767); 425 | resp_text varchar2(32767); 426 | 427 | procedure log_response is 428 | -- needs to commit the log entry independently of calling transaction 429 | pragma autonomous_transaction; 430 | log clicksend_msg_log%rowtype; 431 | begin 432 | logger.log('log_response', scope, null, params); 433 | 434 | log.sent_ts := systimestamp; 435 | log.message_type := p_payload.message_type; 436 | log.requested_ts := p_payload.requested_ts; 437 | log.schedule_dt := p_payload.schedule_dt; 438 | log.sender := p_payload.sender; 439 | log.recipient := p_payload.recipient; 440 | log.subject := p_payload.subject; 441 | log.message := p_payload.message; 442 | log.media_file := p_payload.media_file; 443 | log.voice_lang := p_payload.voice_lang; 444 | log.voice_gender := p_payload.voice_gender; 445 | log.country := p_payload.country; 446 | log.reply_email := p_payload.reply_email; 447 | log.custom_string := p_payload.custom_string; 448 | log.clicksend_response := substr(resp_text, 1, 4000); 449 | 450 | begin 451 | apex_json.parse(resp_text); 452 | 453 | log.clicksend_messageid := apex_json.get_varchar2('data.messages[1].message_id'); 454 | log.clicksend_result := apex_json.get_number('http_code'); 455 | log.clicksend_errortext := apex_json.get_varchar2('response_code'); 456 | log.clicksend_cost := apex_json.get_number('data.total_price'); 457 | exception 458 | when others then 459 | -- log the parse problem but don't stop the logging 460 | logger.log_warning(SQLERRM, scope, resp_text, params); 461 | end; 462 | 463 | insert into clicksend_msg_log values log; 464 | logger.log('inserted clicksend_msg_log: ' || sql%rowcount, scope, null, params); 465 | 466 | logger.log('commit', scope, null, params); 467 | commit; 468 | 469 | end log_response; 470 | 471 | begin 472 | logger.append_param(params,'p_payload.message_type',p_payload.message_type); 473 | logger.append_param(params,'p_payload.requested_ts',p_payload.requested_ts); 474 | logger.append_param(params,'p_payload.schedule_dt',p_payload.schedule_dt); 475 | logger.append_param(params,'p_payload.sender',p_payload.sender); 476 | logger.append_param(params,'p_payload.recipient',p_payload.recipient); 477 | logger.append_param(params,'p_payload.subject',p_payload.subject); 478 | logger.append_param(params,'p_payload.message',p_payload.message); 479 | logger.append_param(params,'p_payload.media_file',p_payload.media_file); 480 | logger.append_param(params,'p_payload.voice_lang',p_payload.voice_lang); 481 | logger.append_param(params,'p_payload.voice_gender',p_payload.voice_gender); 482 | logger.append_param(params,'p_payload.country',p_payload.country); 483 | logger.append_param(params,'p_payload.reply_email',p_payload.reply_email); 484 | logger.append_param(params,'p_payload.custom_string',p_payload.custom_string); 485 | logger.log('START', scope, null, params); 486 | 487 | assert(p_payload.message_type in (message_type_sms, message_type_mms, message_type_voice) 488 | ,'message_type must be sms, mms or voice'); 489 | 490 | prod_check 491 | (p_is_prod => is_prod 492 | ,p_non_prod_recipient => non_prod_recipient 493 | ); 494 | 495 | if not is_prod and non_prod_recipient is not null then 496 | 497 | -- replace recipient with the non-prod recipient 498 | recipient := non_prod_recipient; 499 | 500 | else 501 | 502 | recipient := p_payload.recipient; 503 | 504 | end if; 505 | 506 | begin 507 | apex_json.initialize_clob_output; 508 | apex_json.open_object; 509 | if p_payload.media_file is not null then 510 | apex_json.write('media_file', p_payload.media_file); 511 | end if; 512 | apex_json.open_array('messages'); 513 | apex_json.open_object; 514 | apex_json.write('source', 'oracle'); 515 | if p_payload.message_type in (message_type_sms, message_type_mms) then 516 | apex_json.write('from', p_payload.sender); 517 | end if; 518 | if p_payload.message_type = message_type_mms then 519 | apex_json.write('subject', p_payload.subject); 520 | end if; 521 | apex_json.write('body', p_payload.message); 522 | apex_json.write('to', recipient); 523 | if p_payload.message_type = message_type_voice then 524 | apex_json.write('lang', p_payload.voice_lang); 525 | apex_json.write('voice', p_payload.voice_gender); 526 | end if; 527 | if p_payload.schedule_dt is not null then 528 | apex_json.write('schedule', get_epoch(p_payload.schedule_dt)); 529 | end if; 530 | if p_payload.custom_string is not null then 531 | apex_json.write('custom_string', p_payload.custom_string); 532 | end if; 533 | if p_payload.country is not null then 534 | apex_json.write('country', p_payload.country); 535 | end if; 536 | if p_payload.reply_email is not null then 537 | apex_json.write('from_email', p_payload.reply_email); 538 | end if; 539 | apex_json.close_all; 540 | payload := apex_json.get_clob_output; 541 | apex_json.free_output; 542 | exception 543 | when others then 544 | apex_json.free_output; 545 | raise; 546 | end; 547 | 548 | if is_prod or non_prod_recipient is not null then 549 | 550 | resp_text := get_json 551 | (p_url => setting(setting_api_url) || p_payload.message_type || '/send' 552 | ,p_method => 'POST' 553 | ,p_data => payload 554 | ,p_user => setting(setting_clicksend_username) 555 | ,p_pwd => setting(setting_clicksend_secret_key) 556 | ); 557 | 558 | else 559 | 560 | logger.log_warning('message suppressed', scope, null, params); 561 | 562 | resp_text := 'message suppressed: ' || sys_context('userenv','db_name'); 563 | 564 | end if; 565 | 566 | log_response; 567 | 568 | logger.log('END', scope); 569 | exception 570 | when others then 571 | logger.log_error('Unhandled Exception', scope, null, params); 572 | raise; 573 | end send_msg; 574 | 575 | -- convert '0408123456' to '+61408123456' 576 | function local_to_intnl_au 577 | (p_mobile in varchar2 578 | ,p_country in varchar2 579 | ) return varchar2 is 580 | scope logger_logs.scope%type := scope_prefix || 'local_to_intnl_au'; 581 | params logger.tab_param; 582 | ret varchar2(20) := substr(p_mobile, 1, 20); 583 | begin 584 | logger.append_param(params,'p_mobile',p_mobile); 585 | logger.log('START', scope, null, params); 586 | 587 | if substr(ret, 1, 1) != '+' 588 | and p_country = 'AU' then 589 | ret := '+61' || substr(ret, 2); 590 | end if; 591 | 592 | logger.log('END', scope); 593 | return ret; 594 | exception 595 | when others then 596 | logger.log_error('Unhandled Exception', scope, null, params); 597 | raise; 598 | end local_to_intnl_au; 599 | 600 | -- comma-delimited list of attributes, plus values if required 601 | function json_members_csv 602 | (p_path in varchar2 603 | ,p0 in varchar2 604 | ,p_values in boolean 605 | ) return varchar2 is 606 | scope logger_logs.scope%type := scope_prefix || 'json_members_csv'; 607 | params logger.tab_param; 608 | arr wwv_flow_t_varchar2; 609 | buf varchar2(32767); 610 | begin 611 | logger.append_param(params,'p_path',p_path); 612 | logger.append_param(params,'p0',p0); 613 | logger.append_param(params,'p_values',p_values); 614 | logger.log('START', scope, null, params); 615 | 616 | arr := apex_json.get_members(p_path, p0); 617 | if arr.count > 0 then 618 | for i in 1..arr.count loop 619 | if buf is not null then 620 | buf := buf || ','; 621 | end if; 622 | buf := buf || arr(i); 623 | if p_values then 624 | buf := buf || '=' || apex_json.get_varchar2(p_path || '.' || arr(i), p0); 625 | end if; 626 | end loop; 627 | end if; 628 | 629 | logger.log('END', scope, null, params); 630 | return buf; 631 | exception 632 | when value_error /*not an array or object*/ then 633 | logger.log('END value_error', scope, null, params); 634 | return null; 635 | when others then 636 | logger.log_error('Unhandled Exception', scope, null, params); 637 | raise; 638 | end json_members_csv; 639 | 640 | -------------------------------------------------------------------------------- 641 | --------------------------------- PUBLIC METHODS ------------------------------ 642 | -------------------------------------------------------------------------------- 643 | 644 | procedure init 645 | (p_clicksend_username in varchar2 := default_no_change 646 | ,p_clicksend_secret_key in varchar2 := default_no_change 647 | ,p_api_url in varchar2 := default_no_change 648 | ,p_wallet_path in varchar2 := default_no_change 649 | ,p_wallet_password in varchar2 := default_no_change 650 | ,p_default_sender in varchar2 := default_no_change 651 | ,p_default_country in varchar2 := default_no_change 652 | ,p_default_voice_lang in varchar2 := default_no_change 653 | ,p_default_voice_gender in varchar2 := default_no_change 654 | ,p_voice_preamble in varchar2 := default_no_change 655 | ,p_log_retention_days in number := null 656 | ,p_queue_expiration in number := null 657 | ,p_prod_instance_name in varchar2 := default_no_change 658 | ,p_non_prod_recipient in varchar2 := default_no_change 659 | ) is 660 | scope logger_logs.scope%type := scope_prefix || 'init'; 661 | params logger.tab_param; 662 | begin 663 | logger.append_param(params,'p_clicksend_username',p_clicksend_username); 664 | logger.append_param(params,'p_clicksend_secret_key',case when p_clicksend_secret_key is null then 'null' else 'not null' end); 665 | logger.append_param(params,'p_api_url',p_api_url); 666 | logger.append_param(params,'p_wallet_path',p_wallet_path); 667 | logger.append_param(params,'p_wallet_password',case when p_wallet_password is null then 'null' else 'not null' end); 668 | logger.append_param(params,'p_log_retention_days',p_log_retention_days); 669 | logger.append_param(params,'p_default_sender',p_default_sender); 670 | logger.append_param(params,'p_default_country',p_default_country); 671 | logger.append_param(params,'p_default_voice_lang',p_default_voice_lang); 672 | logger.append_param(params,'p_default_voice_gender',p_default_voice_gender); 673 | logger.append_param(params,'p_voice_preamble',p_voice_preamble); 674 | logger.append_param(params,'p_queue_expiration',p_queue_expiration); 675 | logger.append_param(params,'p_prod_instance_name',p_prod_instance_name); 676 | logger.append_param(params,'p_non_prod_recipient',p_non_prod_recipient); 677 | logger.log('START', scope, null, params); 678 | 679 | if nvl(p_clicksend_username,'*') != default_no_change then 680 | set_setting(setting_clicksend_username, p_clicksend_username); 681 | end if; 682 | 683 | if nvl(p_clicksend_secret_key,'*') != default_no_change then 684 | set_setting(setting_clicksend_secret_key, p_clicksend_secret_key); 685 | end if; 686 | 687 | if nvl(p_api_url,'*') != default_no_change then 688 | -- make sure the url ends with a / 689 | set_setting(setting_api_url, p_api_url 690 | || case when substr(p_api_url,-1,1) != '/' then '/' end); 691 | end if; 692 | 693 | if nvl(p_wallet_path,'*') != default_no_change then 694 | set_setting(setting_wallet_path, p_wallet_path); 695 | end if; 696 | 697 | if nvl(p_wallet_password,'*') != default_no_change then 698 | set_setting(setting_wallet_password, p_wallet_password); 699 | end if; 700 | 701 | if nvl(p_default_sender,'*') != default_no_change then 702 | set_setting(setting_default_sender, p_default_sender); 703 | end if; 704 | 705 | if nvl(p_default_country,'*') != default_no_change then 706 | set_setting(setting_default_country, p_default_country); 707 | end if; 708 | 709 | if nvl(p_default_voice_lang,'*') != default_no_change then 710 | set_setting(setting_default_voice_lang, p_default_voice_lang); 711 | end if; 712 | 713 | if nvl(p_default_voice_gender,'*') != default_no_change then 714 | set_setting(setting_default_voice_gender, p_default_voice_gender); 715 | end if; 716 | 717 | if nvl(p_voice_preamble,'*') != default_no_change then 718 | set_setting(setting_voice_preamble, p_voice_preamble); 719 | end if; 720 | 721 | if p_log_retention_days is not null then 722 | set_setting(setting_log_retention_days, p_log_retention_days); 723 | end if; 724 | 725 | if p_queue_expiration is not null then 726 | set_setting(setting_queue_expiration, p_queue_expiration); 727 | end if; 728 | 729 | if nvl(p_prod_instance_name,'*') != default_no_change then 730 | set_setting(setting_prod_instance_name, p_prod_instance_name); 731 | end if; 732 | 733 | if nvl(p_non_prod_recipient,'*') != default_no_change then 734 | set_setting(setting_non_prod_recipient, p_non_prod_recipient); 735 | end if; 736 | 737 | logger.log('END', scope, null, params); 738 | exception 739 | when others then 740 | logger.log_error('Unhandled Exception', scope, null, params); 741 | raise; 742 | end init; 743 | 744 | procedure send_sms 745 | (p_mobile in varchar2 746 | ,p_message in varchar2 747 | ,p_sender in varchar2 := null 748 | ,p_schedule_dt in date := null -- default is ASAP 749 | ,p_country in varchar2 := null 750 | ,p_reply_email in varchar2 := null 751 | ,p_custom_string in varchar2 := null 752 | ,p_priority in number := default_priority -- lower numbers are processed first 753 | ) is 754 | scope logger_logs.scope%type := scope_prefix || 'send_sms'; 755 | params logger.tab_param; 756 | enq_opts sys.dbms_aq.enqueue_options_t; 757 | enq_msg_props sys.dbms_aq.message_properties_t; 758 | payload t_clicksend_msg; 759 | msgid raw(16); 760 | sender varchar2(100); 761 | country varchar2(10); 762 | begin 763 | logger.append_param(params,'p_mobile',p_mobile); 764 | logger.append_param(params,'p_message',p_message); 765 | logger.append_param(params,'p_sender',p_sender); 766 | logger.append_param(params,'p_schedule_dt',p_schedule_dt); 767 | logger.append_param(params,'p_country',p_country); 768 | logger.append_param(params,'p_reply_email',p_reply_email); 769 | logger.append_param(params,'p_custom_string',p_custom_string); 770 | logger.append_param(params,'p_priority',p_priority); 771 | logger.log('START', scope, null, params); 772 | 773 | reset; 774 | 775 | assert(p_mobile is not null, 'p_mobile cannot be null'); 776 | 777 | if substr(p_mobile, 1, 1) = '+' then 778 | assert(length(p_mobile) = 12, 'mobile starting with + must be 12 characters exactly (' || p_mobile || ')'); 779 | assert(replace(translate(substr(p_mobile,2),'0123456789','-'),'-','') is null, 'mobile starting with + must have 11 digits (' || p_mobile || ')'); 780 | else 781 | assert(length(p_mobile) = 10, 'mobile must have 10 digits exactly (' || p_mobile || ') (unless it starts with a +)'); 782 | assert(replace(translate(p_mobile,'0123456789','-'),'-','') is null, 'mobile must be 10 digits (' || p_mobile || ') (unless it starts with a +)'); 783 | end if; 784 | 785 | country := nvl(p_country, setting(setting_default_country)); 786 | 787 | if country = 'AU' then 788 | assert(substr(p_mobile, 1, 2) in ('04', '05') or substr(p_mobile, 1, 4) in ('+614', '+615'), 'AU mobile must start with 04 or 05 (or +614 or +615)'); 789 | end if; 790 | 791 | assert(p_message is not null, 'p_message cannot be null'); 792 | assert(length(p_message) <= 960, 'maximum message length is 960 (' || length(p_message) || ')'); 793 | 794 | sender := nvl(p_sender, setting(setting_default_sender)); 795 | assert(sender is not null, 'sender cannot be null'); 796 | assert(length(sender) <= 11, 'sender cannot be >11 characters (' || sender || ')'); 797 | 798 | assert(length(p_reply_email) <= 255, 'p_reply_email cannot be >255 characters'); 799 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 800 | 801 | payload := t_clicksend_msg 802 | (message_type => message_type_sms 803 | ,requested_ts => systimestamp 804 | ,schedule_dt => p_schedule_dt 805 | ,sender => sender 806 | ,recipient => local_to_intnl_au(p_mobile, country) 807 | ,subject => '' 808 | ,message => p_message 809 | ,media_file => '' 810 | ,voice_lang => '' 811 | ,voice_gender => '' 812 | ,country => country 813 | ,reply_email => p_reply_email 814 | ,custom_string => p_custom_string 815 | ); 816 | 817 | enq_msg_props.expiration := setting(setting_queue_expiration); 818 | enq_msg_props.priority := p_priority; 819 | 820 | sys.dbms_aq.enqueue 821 | (queue_name => queue_name 822 | ,enqueue_options => enq_opts 823 | ,message_properties => enq_msg_props 824 | ,payload => payload 825 | ,msgid => msgid 826 | ); 827 | 828 | logger.log('msg queued ' || msgid, scope, null, params); 829 | 830 | logger.log('END', scope); 831 | exception 832 | when others then 833 | logger.log_error('Unhandled Exception', scope, null, params); 834 | raise; 835 | end send_sms; 836 | 837 | procedure send_mms 838 | (p_mobile in varchar2 839 | ,p_subject in varchar2 840 | ,p_message in varchar2 841 | ,p_media_file_url in varchar2 842 | ,p_sender in varchar2 := null 843 | ,p_schedule_dt in date := null -- default is ASAP 844 | ,p_country in varchar2 := null 845 | ,p_reply_email in varchar2 := null 846 | ,p_custom_string in varchar2 := null 847 | ,p_priority in number := default_priority -- lower numbers are processed first 848 | ) is 849 | scope logger_logs.scope%type := scope_prefix || 'send_mms'; 850 | params logger.tab_param; 851 | enq_opts sys.dbms_aq.enqueue_options_t; 852 | enq_msg_props sys.dbms_aq.message_properties_t; 853 | payload t_clicksend_msg; 854 | msgid raw(16); 855 | sender varchar2(100); 856 | country varchar2(10); 857 | begin 858 | logger.append_param(params,'p_mobile',p_mobile); 859 | logger.append_param(params,'p_subject',p_subject); 860 | logger.append_param(params,'p_message',p_message); 861 | logger.append_param(params,'p_media_file_url',p_media_file_url); 862 | logger.append_param(params,'p_sender',p_sender); 863 | logger.append_param(params,'p_schedule_dt',p_schedule_dt); 864 | logger.append_param(params,'p_country',p_country); 865 | logger.append_param(params,'p_reply_email',p_reply_email); 866 | logger.append_param(params,'p_custom_string',p_custom_string); 867 | logger.append_param(params,'p_priority',p_priority); 868 | logger.log('START', scope, null, params); 869 | 870 | reset; 871 | 872 | assert(p_mobile is not null, 'p_mobile cannot be null'); 873 | 874 | assert(p_subject is not null, 'p_subject cannot be null'); 875 | assert(length(p_subject) <= 20, 'maximum subject length is 20 (' || length(p_subject) || ')'); 876 | 877 | assert(p_media_file_url is not null, 'p_media_file_url cannot be null'); 878 | 879 | if substr(p_mobile, 1, 1) = '+' then 880 | assert(length(p_mobile) = 12, 'mobile starting with + must be 12 characters exactly (' || p_mobile || ')'); 881 | assert(replace(translate(substr(p_mobile,2),'0123456789','-'),'-','') is null, 'mobile starting with + must have 11 digits (' || p_mobile || ')'); 882 | else 883 | assert(length(p_mobile) = 10, 'mobile must have 10 digits exactly (' || p_mobile || ') (unless it starts with a +)'); 884 | assert(replace(translate(p_mobile,'0123456789','-'),'-','') is null, 'mobile must be 10 digits (' || p_mobile || ') (unless it starts with a +)'); 885 | end if; 886 | 887 | country := nvl(p_country, setting(setting_default_country)); 888 | 889 | if country = 'AU' then 890 | assert(substr(p_mobile, 1, 2) in ('04', '05') or substr(p_mobile, 1, 4) in ('+614', '+615'), 'AU mobile must start with 04 or 05 (or +614 or +615)'); 891 | end if; 892 | 893 | assert(p_message is not null, 'p_message cannot be null'); 894 | assert(length(p_message) <= 1500, 'maximum message length is 1500 (' || length(p_message) || ')'); 895 | 896 | sender := nvl(p_sender, setting(setting_default_sender)); 897 | assert(sender is not null, 'sender cannot be null'); 898 | assert(length(sender) <= 11, 'sender cannot be >11 characters (' || sender || ')'); 899 | 900 | assert(length(p_reply_email) <= 255, 'p_reply_email cannot be >255 characters'); 901 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 902 | 903 | payload := t_clicksend_msg 904 | (message_type => message_type_mms 905 | ,requested_ts => systimestamp 906 | ,schedule_dt => p_schedule_dt 907 | ,sender => sender 908 | ,recipient => local_to_intnl_au(p_mobile, country) 909 | ,subject => p_subject 910 | ,message => p_message 911 | ,media_file => p_media_file_url 912 | ,voice_lang => '' 913 | ,voice_gender => '' 914 | ,country => country 915 | ,reply_email => p_reply_email 916 | ,custom_string => p_custom_string 917 | ); 918 | 919 | enq_msg_props.expiration := setting(setting_queue_expiration); 920 | enq_msg_props.priority := p_priority; 921 | 922 | sys.dbms_aq.enqueue 923 | (queue_name => queue_name 924 | ,enqueue_options => enq_opts 925 | ,message_properties => enq_msg_props 926 | ,payload => payload 927 | ,msgid => msgid 928 | ); 929 | 930 | logger.log('msg queued ' || msgid, scope, null, params); 931 | 932 | logger.log('END', scope); 933 | exception 934 | when others then 935 | logger.log_error('Unhandled Exception', scope, null, params); 936 | raise; 937 | end send_mms; 938 | 939 | procedure send_voice 940 | (p_phone_no in varchar2 941 | ,p_message in varchar2 942 | ,p_voice_lang in varchar2 := null 943 | ,p_voice_gender in varchar2 := null 944 | ,p_schedule_dt in date := null -- default is ASAP 945 | ,p_country in varchar2 := null 946 | ,p_custom_string in varchar2 := null 947 | ,p_priority in number := default_priority -- lower numbers are processed first 948 | ) is 949 | scope logger_logs.scope%type := scope_prefix || 'send_voice'; 950 | params logger.tab_param; 951 | enq_opts sys.dbms_aq.enqueue_options_t; 952 | enq_msg_props sys.dbms_aq.message_properties_t; 953 | payload t_clicksend_msg; 954 | msgid raw(16); 955 | message varchar2(4000); 956 | voice_lang varchar2(100); 957 | voice_gender varchar2(6); 958 | country varchar2(10); 959 | begin 960 | logger.append_param(params,'p_phone_no',p_phone_no); 961 | logger.append_param(params,'p_message',p_message); 962 | logger.append_param(params,'p_voice_lang',p_voice_lang); 963 | logger.append_param(params,'p_voice_gender',p_voice_gender); 964 | logger.append_param(params,'p_schedule_dt',p_schedule_dt); 965 | logger.append_param(params,'p_country',p_country); 966 | logger.append_param(params,'p_custom_string',p_custom_string); 967 | logger.append_param(params,'p_priority',p_priority); 968 | logger.log('START', scope, null, params); 969 | 970 | reset; 971 | 972 | assert(p_phone_no is not null, 'p_phone_no cannot be null'); 973 | 974 | if substr(p_phone_no, 1, 1) = '+' then 975 | assert(length(p_phone_no) = 12, 'phone_no starting with + must be 12 characters exactly (' || p_phone_no || ')'); 976 | assert(replace(translate(substr(p_phone_no,2),'0123456789','-'),'-','') is null, 'phone_no starting with + must have 11 digits (' || p_phone_no || ')'); 977 | else 978 | assert(length(p_phone_no) = 10, 'phone_no must have 10 digits exactly (' || p_phone_no || ') (unless it starts with a +)'); 979 | assert(replace(translate(p_phone_no,'0123456789','-'),'-','') is null, 'phone_no must be 10 digits (' || p_phone_no || ') (unless it starts with a +)'); 980 | end if; 981 | 982 | country := nvl(p_country, setting(setting_default_country)); 983 | 984 | assert(p_message is not null, 'p_message cannot be null'); 985 | message := substr(setting(setting_voice_preamble) || p_message, 1, 4000); 986 | assert(length(message) <= 1200, 'maximum message length is 1200 (' || length(message) || ') including preamble'); 987 | 988 | voice_lang := nvl(p_voice_lang, setting(setting_default_voice_lang)); 989 | assert(voice_lang is not null, 'voice_lang cannot be null'); 990 | 991 | voice_gender := nvl(p_voice_gender, setting(setting_default_voice_gender)); 992 | assert(voice_gender in ('female','male'), 'voice_gender must be female or male'); 993 | 994 | assert(length(p_custom_string) <= 4000, 'p_custom_string cannot be >4000 characters'); 995 | 996 | payload := t_clicksend_msg 997 | (message_type => message_type_voice 998 | ,requested_ts => systimestamp 999 | ,schedule_dt => p_schedule_dt 1000 | ,sender => '' 1001 | ,recipient => p_phone_no 1002 | ,subject => '' 1003 | ,message => message 1004 | ,media_file => '' 1005 | ,voice_lang => voice_lang 1006 | ,voice_gender => voice_gender 1007 | ,country => country 1008 | ,reply_email => '' 1009 | ,custom_string => p_custom_string 1010 | ); 1011 | 1012 | enq_msg_props.expiration := setting(setting_queue_expiration); 1013 | enq_msg_props.priority := p_priority; 1014 | 1015 | sys.dbms_aq.enqueue 1016 | (queue_name => queue_name 1017 | ,enqueue_options => enq_opts 1018 | ,message_properties => enq_msg_props 1019 | ,payload => payload 1020 | ,msgid => msgid 1021 | ); 1022 | 1023 | logger.log('msg queued ' || msgid, scope, null, params); 1024 | 1025 | logger.log('END', scope); 1026 | exception 1027 | when others then 1028 | logger.log_error('Unhandled Exception', scope, null, params); 1029 | raise; 1030 | end send_voice; 1031 | 1032 | function get_account_details return varchar2 is 1033 | pragma autonomous_transaction; 1034 | scope logger_logs.scope%type := scope_prefix || 'get_account_details'; 1035 | params logger.tab_param; 1036 | v_json varchar2(32767); 1037 | begin 1038 | logger.log('START', scope, null, params); 1039 | 1040 | reset; 1041 | 1042 | v_json := get_json 1043 | (p_url => setting(setting_api_url) || 'account' 1044 | ,p_method => 'GET' 1045 | ,p_user => setting(setting_clicksend_username) 1046 | ,p_pwd => setting(setting_clicksend_secret_key) 1047 | ,p_accept => 'application/json' 1048 | ); 1049 | 1050 | logger.log('END', scope); 1051 | return v_json; 1052 | exception 1053 | when others then 1054 | logger.log_error('Unhandled Exception', scope, null, params); 1055 | raise; 1056 | end get_account_details; 1057 | 1058 | function get_credit_balance return number is 1059 | scope logger_logs.scope%type := scope_prefix || 'get_credit_balance'; 1060 | params logger.tab_param; 1061 | v_json varchar2(4000); 1062 | v_bal varchar2(4000); 1063 | begin 1064 | logger.log('START', scope, null, params); 1065 | 1066 | v_json := get_account_details; 1067 | 1068 | apex_json.parse(v_json); 1069 | 1070 | v_bal := apex_json.get_varchar2('data.balance'); 1071 | 1072 | logger.log('END', scope); 1073 | return to_number(v_bal); 1074 | exception 1075 | when value_error then 1076 | logger.log_error('get_credit_balance: unable to convert balance "' || v_bal || '"', scope, null, params); 1077 | raise; 1078 | when others then 1079 | logger.log_error('Unhandled Exception', scope, null, params); 1080 | raise; 1081 | end get_credit_balance; 1082 | 1083 | function get_languages return t_clicksend_lang_arr pipelined is 1084 | scope logger_logs.scope%type := scope_prefix || 'get_languages'; 1085 | params logger.tab_param; 1086 | v_json varchar2(32767); 1087 | data_count number; 1088 | gender apex_json.t_value; 1089 | gender1 varchar2(10); 1090 | gender2 varchar2(10); 1091 | begin 1092 | logger.log('START', scope, null, params); 1093 | 1094 | v_json := get_json 1095 | (p_url => setting(setting_api_url) || 'voice/lang' 1096 | ,p_method => 'GET' 1097 | ,p_user => setting(setting_clicksend_username) 1098 | ,p_pwd => setting(setting_clicksend_secret_key) 1099 | ,p_accept => 'application/json' 1100 | ); 1101 | 1102 | apex_json.parse(v_json); 1103 | 1104 | data_count := apex_json.get_count('data'); 1105 | 1106 | if data_count > 0 then 1107 | for i in 1..data_count loop 1108 | logger.log(i||' '||json_members_csv('data[%d]', i, p_values => true), scope, null, params); 1109 | 1110 | gender1 := null; 1111 | gender2 := null; 1112 | gender := apex_json.get_value('data[%d].gender', i); 1113 | 1114 | -- perversely, the gender node might be a simple value (e.g. "gender":"female") 1115 | -- or it might be an array (e.g. "gender":["female","male"]) 1116 | if gender.kind = apex_json.c_varchar2 then 1117 | gender1 := gender.varchar2_value; 1118 | elsif gender.kind = apex_json.c_array then 1119 | gender1 := apex_json.get_varchar2('data[%d].gender[1]', i); 1120 | gender2 := apex_json.get_varchar2('data[%d].gender[2]', i); 1121 | end if; 1122 | 1123 | pipe row (t_clicksend_lang 1124 | (lang_code => substr(apex_json.get_varchar2('data[%d].code', i), 1, 10) 1125 | ,country_desc => substr(apex_json.get_varchar2('data[%d].country', i), 1, 100) 1126 | ,female => case when voice_female in (gender1,gender2) then 'Y' end 1127 | ,male => case when voice_male in (gender1,gender2) then 'Y' end 1128 | )); 1129 | 1130 | end loop; 1131 | end if; 1132 | 1133 | logger.log('END', scope); 1134 | return; 1135 | exception 1136 | when others then 1137 | logger.log_error('Unhandled Exception', scope, null, params); 1138 | raise; 1139 | end get_languages; 1140 | 1141 | function get_countries return t_clicksend_country_arr pipelined is 1142 | scope logger_logs.scope%type := scope_prefix || 'get_countries'; 1143 | params logger.tab_param; 1144 | v_json varchar2(32767); 1145 | data_count number; 1146 | begin 1147 | logger.log('START', scope, null, params); 1148 | 1149 | v_json := get_json 1150 | (p_url => setting(setting_api_url) || 'countries' 1151 | ,p_method => 'GET' 1152 | ,p_accept => 'application/json' 1153 | ); 1154 | 1155 | apex_json.parse(v_json); 1156 | 1157 | data_count := apex_json.get_count('data'); 1158 | 1159 | if data_count > 0 then 1160 | for i in 1..data_count loop 1161 | logger.log(i||' '||json_members_csv('data[%d]', i, p_values => true), scope, null, params); 1162 | 1163 | pipe row (t_clicksend_country 1164 | (country_code => substr(apex_json.get_varchar2('data[%d].code', i), 1, 10) 1165 | ,country_name => substr(apex_json.get_varchar2('data[%d].value', i), 1, 100) 1166 | )); 1167 | 1168 | end loop; 1169 | end if; 1170 | 1171 | logger.log('END', scope); 1172 | return; 1173 | exception 1174 | when others then 1175 | logger.log_error('Unhandled Exception', scope, null, params); 1176 | raise; 1177 | end get_countries; 1178 | 1179 | function get_sms_history 1180 | (p_from in date := null -- default is 7 days prior to p_until 1181 | ,p_until in date := null -- default is sysdate 1182 | ) return t_clicksend_sms_history_arr pipelined is 1183 | scope logger_logs.scope%type := scope_prefix || 'get_sms_history'; 1184 | params logger.tab_param; 1185 | prm varchar2(4000); 1186 | url varchar2(4000); 1187 | v_json varchar2(32767); 1188 | data_count number; 1189 | page_count number := 1; 1190 | begin 1191 | logger.append_param(params,'p_from',p_from); 1192 | logger.append_param(params,'p_until',p_until); 1193 | logger.log('START', scope, null, params); 1194 | 1195 | url_param(prm, 'date_from', nvl(p_from, nvl(p_until, sysdate) - 7)); 1196 | url_param(prm, 'date_to', nvl(p_until, sysdate)); 1197 | 1198 | v_json := get_json 1199 | (p_url => setting(setting_api_url) || 'sms/history' 1200 | ,p_method => 'GET' 1201 | ,p_params => prm 1202 | ,p_user => setting(setting_clicksend_username) 1203 | ,p_pwd => setting(setting_clicksend_secret_key) 1204 | ,p_accept => 'application/json' 1205 | ); 1206 | 1207 | loop 1208 | 1209 | apex_json.parse(v_json); 1210 | 1211 | data_count := apex_json.get_count('data.data'); 1212 | logger.log('total=' || apex_json.get_number('data.total'), scope, null, params); 1213 | logger.log('current_page=' || apex_json.get_number('data.current_page'), scope, null, params); 1214 | 1215 | if data_count > 0 then 1216 | for i in 1..data_count loop 1217 | logger.log(i||' '||json_members_csv('data.data[%d]', i, p_values => true), scope, null, params); 1218 | 1219 | pipe row (t_clicksend_sms_history 1220 | (event_dt => epoch_to_dt(apex_json.get_varchar2('data.data[%d].date', i)) 1221 | ,mobile => substr(apex_json.get_varchar2('data.data[%d].to', i), 1, 20) 1222 | ,message => substr(apex_json.get_varchar2('data.data[%d].body', i), 1, 4000) 1223 | ,status => substr(apex_json.get_varchar2('data.data[%d].status', i), 1, 100) 1224 | ,sender => substr(apex_json.get_varchar2('data.data[%d].from', i), 1, 100) 1225 | ,schedule_dt => epoch_to_dt(apex_json.get_varchar2('data.data[%d].schedule', i)) 1226 | ,status_code => substr(apex_json.get_varchar2('data.data[%d].status_code', i), 1, 100) 1227 | ,status_text => substr(apex_json.get_varchar2('data.data[%d].status_text', i), 1, 4000) 1228 | ,error_code => substr(apex_json.get_varchar2('data.data[%d].error_code', i), 1, 100) 1229 | ,error_text => substr(apex_json.get_varchar2('data.data[%d].error_text', i), 1, 4000) 1230 | ,message_id => substr(apex_json.get_varchar2('data.data[%d].message_id', i), 1, 4000) 1231 | ,message_parts => to_number(apex_json.get_varchar2('data.data[%d].message_parts', i)) 1232 | ,message_price => to_number(apex_json.get_varchar2('data.data[%d].message_price', i)) 1233 | ,reply_email => substr(apex_json.get_varchar2('data.data[%d].from_email', i), 1, 255) 1234 | ,custom_string => substr(apex_json.get_varchar2('data.data[%d].custom_string', i), 1, 4000) 1235 | ,subaccount_id => apex_json.get_number('data.data[%d].subaccount_id', i) 1236 | ,country => substr(apex_json.get_varchar2('data.data[%d].country', i), 1, 10) 1237 | ,carrier => substr(apex_json.get_varchar2('data.data[%d].carrier', i), 1, 100) 1238 | )); 1239 | 1240 | end loop; 1241 | end if; 1242 | 1243 | url := apex_json.get_varchar2('data.next_page_url'); 1244 | logger.log('url='||url, scope, null, params); 1245 | 1246 | exit when url is null; 1247 | 1248 | v_json := get_json 1249 | (p_url => setting(setting_api_url) || 'sms/history' || url 1250 | ,p_method => 'GET' 1251 | ,p_user => setting(setting_clicksend_username) 1252 | ,p_pwd => setting(setting_clicksend_secret_key) 1253 | ,p_accept => 'application/json' 1254 | ); 1255 | 1256 | page_count := page_count + 1; 1257 | 1258 | exit when page_count > 10; 1259 | 1260 | end loop; 1261 | 1262 | logger.log('END', scope); 1263 | return; 1264 | exception 1265 | when others then 1266 | logger.log_error('Unhandled Exception', scope, null, params); 1267 | raise; 1268 | end get_sms_history; 1269 | 1270 | procedure create_queue 1271 | (p_max_retries in number := default_max_retries 1272 | ,p_retry_delay in number := default_retry_delay 1273 | ) is 1274 | scope logger_logs.scope%type := scope_prefix || 'create_queue'; 1275 | params logger.tab_param; 1276 | begin 1277 | logger.append_param(params,'p_max_retries',p_max_retries); 1278 | logger.append_param(params,'p_retry_delay',p_retry_delay); 1279 | logger.log('START', scope, null, params); 1280 | 1281 | sys.dbms_aqadm.create_queue_table 1282 | (queue_table => queue_table 1283 | ,queue_payload_type => payload_type 1284 | ,sort_list => 'priority,enq_time' 1285 | ); 1286 | 1287 | sys.dbms_aqadm.create_queue 1288 | (queue_name => queue_name 1289 | ,queue_table => queue_table 1290 | ,max_retries => p_max_retries 1291 | ,retry_delay => p_retry_delay 1292 | ); 1293 | 1294 | sys.dbms_aqadm.start_queue (queue_name); 1295 | 1296 | logger.log('END', scope, null, params); 1297 | exception 1298 | when others then 1299 | logger.log_error('Unhandled Exception', scope, null, params); 1300 | raise; 1301 | end create_queue; 1302 | 1303 | procedure drop_queue is 1304 | scope logger_logs.scope%type := scope_prefix || 'drop_queue'; 1305 | params logger.tab_param; 1306 | begin 1307 | logger.log('START', scope, null, params); 1308 | 1309 | sys.dbms_aqadm.stop_queue (queue_name); 1310 | 1311 | sys.dbms_aqadm.drop_queue (queue_name); 1312 | 1313 | sys.dbms_aqadm.drop_queue_table (queue_table); 1314 | 1315 | logger.log('END', scope, null, params); 1316 | exception 1317 | when others then 1318 | logger.log_error('Unhandled Exception', scope, null, params); 1319 | raise; 1320 | end drop_queue; 1321 | 1322 | procedure purge_queue (p_msg_state IN VARCHAR2 := default_purge_msg_state) is 1323 | scope logger_logs.scope%type := scope_prefix || 'purge_queue'; 1324 | params logger.tab_param; 1325 | r_opt sys.dbms_aqadm.aq$_purge_options_t; 1326 | begin 1327 | logger.append_param(params,'p_msg_state',p_msg_state); 1328 | logger.log('START', scope, null, params); 1329 | 1330 | sys.dbms_aqadm.purge_queue_table 1331 | (queue_table => queue_table 1332 | ,purge_condition => case when p_msg_state is not null 1333 | then replace(q'[ qtview.msg_state = '#STATE#' ]' 1334 | ,'#STATE#', p_msg_state) 1335 | end 1336 | ,purge_options => r_opt); 1337 | 1338 | logger.log('END', scope, null, params); 1339 | exception 1340 | when others then 1341 | logger.log_error('Unhandled Exception', scope, null, params); 1342 | raise; 1343 | end purge_queue; 1344 | 1345 | procedure push_queue 1346 | (p_asynchronous in boolean := false) as 1347 | scope logger_logs.scope%type := scope_prefix || 'push_queue'; 1348 | params logger.tab_param; 1349 | r_dequeue_options sys.dbms_aq.dequeue_options_t; 1350 | r_message_properties sys.dbms_aq.message_properties_t; 1351 | msgid raw(16); 1352 | payload t_clicksend_msg; 1353 | dequeue_count integer := 0; 1354 | job binary_integer; 1355 | begin 1356 | logger.append_param(params,'p_asynchronous',p_asynchronous); 1357 | logger.log('START', scope, null, params); 1358 | 1359 | if p_asynchronous then 1360 | 1361 | -- use dbms_job so that it is only run if/when this session commits 1362 | 1363 | sys.dbms_job.submit 1364 | (job => job 1365 | ,what => $$plsql_unit || '.push_queue;' 1366 | ); 1367 | 1368 | logger.log('submitted job=' || job, scope, null, params); 1369 | 1370 | else 1371 | 1372 | reset; 1373 | 1374 | -- commit any messages requested in the current session 1375 | logger.log('commit', scope, null, params); 1376 | commit; 1377 | 1378 | r_dequeue_options.wait := sys.dbms_aq.no_wait; 1379 | 1380 | -- loop through all messages in the queue until there is none 1381 | -- exit this loop when the e_no_queue_data exception is raised. 1382 | loop 1383 | 1384 | sys.dbms_aq.dequeue 1385 | (queue_name => queue_name 1386 | ,dequeue_options => r_dequeue_options 1387 | ,message_properties => r_message_properties 1388 | ,payload => payload 1389 | ,msgid => msgid 1390 | ); 1391 | 1392 | logger.log('payload priority: ' || r_message_properties.priority 1393 | || ' enqeued: ' || to_char(r_message_properties.enqueue_time,'dd/mm/yyyy hh24:mi:ss') 1394 | || ' attempts: ' || r_message_properties.attempts 1395 | , scope, null, params); 1396 | 1397 | -- process the message 1398 | send_msg (p_payload => payload); 1399 | 1400 | logger.log('commit', scope, null, params); 1401 | commit; -- the queue will treat the message as succeeded 1402 | 1403 | -- don't bite off everything in one go 1404 | dequeue_count := dequeue_count + 1; 1405 | exit when dequeue_count >= max_dequeue_count; 1406 | end loop; 1407 | 1408 | end if; 1409 | 1410 | logger.log('END', scope, null, params); 1411 | exception 1412 | when e_no_queue_data then 1413 | logger.log('END push_queue finished count=' || dequeue_count, scope, null, params); 1414 | when others then 1415 | rollback; -- the queue will treat the message as failed 1416 | logger.log_error('Unhandled Exception', scope, null, params); 1417 | raise; 1418 | end push_queue; 1419 | 1420 | procedure create_job 1421 | (p_repeat_interval in varchar2 := default_repeat_interval) is 1422 | scope logger_logs.scope%type := scope_prefix || 'create_job'; 1423 | params logger.tab_param; 1424 | begin 1425 | logger.append_param(params,'p_repeat_interval',p_repeat_interval); 1426 | logger.log('START', scope, null, params); 1427 | 1428 | assert(p_repeat_interval is not null, 'create_job: p_repeat_interval cannot be null'); 1429 | 1430 | sys.dbms_scheduler.create_job 1431 | (job_name => job_name 1432 | ,job_type => 'stored_procedure' 1433 | ,job_action => $$plsql_unit||'.push_queue' 1434 | ,start_date => systimestamp 1435 | ,repeat_interval => p_repeat_interval 1436 | ); 1437 | 1438 | sys.dbms_scheduler.set_attribute(job_name,'restartable',true); 1439 | 1440 | sys.dbms_scheduler.enable(job_name); 1441 | 1442 | logger.log('END', scope, null, params); 1443 | exception 1444 | when others then 1445 | logger.log_error('Unhandled Exception', scope, null, params); 1446 | raise; 1447 | end create_job; 1448 | 1449 | procedure drop_job is 1450 | scope logger_logs.scope%type := scope_prefix || 'drop_job'; 1451 | params logger.tab_param; 1452 | begin 1453 | logger.log('START', scope, null, params); 1454 | 1455 | begin 1456 | sys.dbms_scheduler.stop_job (job_name); 1457 | exception 1458 | when others then 1459 | if sqlcode != -27366 /*job already stopped*/ then 1460 | raise; 1461 | end if; 1462 | end; 1463 | 1464 | sys.dbms_scheduler.drop_job (job_name); 1465 | 1466 | logger.log('END', scope, null, params); 1467 | exception 1468 | when others then 1469 | logger.log_error('Unhandled Exception', scope, null, params); 1470 | raise; 1471 | end drop_job; 1472 | 1473 | procedure purge_logs (p_log_retention_days in number := null) is 1474 | scope logger_logs.scope%type := scope_prefix || 'purge_logs'; 1475 | params logger.tab_param; 1476 | l_log_retention_days number; 1477 | begin 1478 | logger.append_param(params,'p_log_retention_days',p_log_retention_days); 1479 | logger.log('START', scope, null, params); 1480 | 1481 | reset; 1482 | 1483 | l_log_retention_days := nvl(p_log_retention_days, log_retention_days); 1484 | logger.append_param(params,'l_log_retention_days',l_log_retention_days); 1485 | 1486 | delete clicksend_msg_log 1487 | where requested_ts < sysdate - l_log_retention_days; 1488 | 1489 | logger.log_info('DELETED clicksend_msg_log: ' || SQL%ROWCOUNT, scope, null, params); 1490 | 1491 | logger.log('commit', scope, null, params); 1492 | commit; 1493 | 1494 | logger.log('END', scope, null, params); 1495 | exception 1496 | when others then 1497 | logger.log_error('Unhandled Exception', scope, null, params); 1498 | raise; 1499 | end purge_logs; 1500 | 1501 | procedure create_purge_job 1502 | (p_repeat_interval in varchar2 := default_purge_repeat_interval) is 1503 | scope logger_logs.scope%type := scope_prefix || 'create_purge_job'; 1504 | params logger.tab_param; 1505 | begin 1506 | logger.append_param(params,'p_repeat_interval',p_repeat_interval); 1507 | logger.log('START', scope, null, params); 1508 | 1509 | assert(p_repeat_interval is not null, 'create_purge_job: p_repeat_interval cannot be null'); 1510 | 1511 | sys.dbms_scheduler.create_job 1512 | (job_name => purge_job_name 1513 | ,job_type => 'stored_procedure' 1514 | ,job_action => $$plsql_unit||'.purge_logs' 1515 | ,start_date => systimestamp 1516 | ,repeat_interval => p_repeat_interval 1517 | ); 1518 | 1519 | sys.dbms_scheduler.set_attribute(job_name,'restartable',true); 1520 | 1521 | sys.dbms_scheduler.enable(purge_job_name); 1522 | 1523 | logger.log('END', scope, null, params); 1524 | exception 1525 | when others then 1526 | logger.log_error('Unhandled Exception', scope, null, params); 1527 | raise; 1528 | end create_purge_job; 1529 | 1530 | procedure drop_purge_job is 1531 | scope logger_logs.scope%type := scope_prefix || 'drop_purge_job'; 1532 | params logger.tab_param; 1533 | begin 1534 | logger.log('START', scope, null, params); 1535 | 1536 | begin 1537 | sys.dbms_scheduler.stop_job (purge_job_name); 1538 | exception 1539 | when others then 1540 | if sqlcode != -27366 /*job already stopped*/ then 1541 | raise; 1542 | end if; 1543 | end; 1544 | 1545 | sys.dbms_scheduler.drop_job (purge_job_name); 1546 | 1547 | logger.log('END', scope, null, params); 1548 | exception 1549 | when others then 1550 | logger.log_error('Unhandled Exception', scope, null, params); 1551 | raise; 1552 | end drop_purge_job; 1553 | 1554 | procedure send_test_sms 1555 | (p_mobile in varchar2 1556 | ,p_message in varchar2 := null 1557 | ,p_sender in varchar2 := null 1558 | ,p_clicksend_username in varchar2 := default_no_change 1559 | ,p_clicksend_secret_key in varchar2 := default_no_change 1560 | ,p_api_url in varchar2 := default_no_change 1561 | ,p_wallet_path in varchar2 := default_no_change 1562 | ,p_wallet_password in varchar2 := default_no_change 1563 | ) is 1564 | scope logger_logs.scope%type := scope_prefix || 'send_test_sms'; 1565 | params logger.tab_param; 1566 | payload t_clicksend_msg; 1567 | begin 1568 | logger.append_param(params,'p_mobile',p_mobile); 1569 | logger.append_param(params,'p_message',p_message); 1570 | logger.append_param(params,'p_sender',p_sender); 1571 | logger.append_param(params,'p_clicksend_username',p_clicksend_username); 1572 | logger.append_param(params,'p_clicksend_secret_key',case when p_clicksend_secret_key is null then 'null' else 'not null' end); 1573 | logger.append_param(params,'p_api_url',p_api_url); 1574 | logger.append_param(params,'p_wallet_path',p_wallet_path); 1575 | logger.append_param(params,'p_wallet_password',case when p_wallet_password is null then 'null' else 'not null' end); 1576 | logger.log('START', scope, null, params); 1577 | 1578 | -- set up settings just for this call 1579 | load_settings; 1580 | if p_clicksend_username != default_no_change then 1581 | g_setting(setting_clicksend_username) := p_clicksend_username; 1582 | end if; 1583 | if p_clicksend_secret_key != default_no_change then 1584 | g_setting(setting_clicksend_secret_key) := p_clicksend_secret_key; 1585 | end if; 1586 | if p_api_url != default_no_change then 1587 | g_setting(setting_api_url) := p_api_url; 1588 | end if; 1589 | if p_wallet_path != default_no_change then 1590 | g_setting(setting_wallet_path) := p_wallet_path; 1591 | end if; 1592 | if p_wallet_password != default_no_change then 1593 | g_setting(setting_wallet_password) := p_wallet_password; 1594 | end if; 1595 | 1596 | payload := t_clicksend_msg 1597 | (message_type => message_type_sms 1598 | ,requested_ts => systimestamp 1599 | ,schedule_dt => null 1600 | ,sender => nvl(p_sender, setting(setting_default_sender)) 1601 | ,recipient => local_to_intnl_au(p_mobile, setting(setting_default_country)) 1602 | ,subject => '' 1603 | ,message => nvl(p_message 1604 | ,'This test message was sent from ' 1605 | || sys_context('userenv','db_name') 1606 | || ' at ' 1607 | || to_char(systimestamp,'DD/MM/YYYY HH24:MI:SS.FF')) 1608 | ,media_file => '' 1609 | ,voice_lang => '' 1610 | ,voice_gender => '' 1611 | ,country => setting(setting_default_country) 1612 | ,reply_email => '' 1613 | ,custom_string => '' 1614 | ); 1615 | 1616 | send_msg(p_payload => payload); 1617 | 1618 | -- reset everything back to normal 1619 | reset; 1620 | 1621 | logger.log('END', scope, null, params); 1622 | exception 1623 | when others then 1624 | logger.log_error('Unhandled Exception', scope, null, params); 1625 | reset; 1626 | raise; 1627 | end send_test_sms; 1628 | 1629 | end clicksend_pkg; 1630 | / 1631 | 1632 | show errors 1633 | -------------------------------------------------------------------------------- /create_tables.sql: -------------------------------------------------------------------------------- 1 | prompt create_tables.sql 2 | -- tables for clicksend v0.1 3 | 4 | drop table clicksend_msg_log; 5 | 6 | -- table to record logs of sent/attempted sms's 7 | create table clicksend_msg_log 8 | ( message_type varchar2(20 char) -- sms, mms, voice 9 | , requested_ts timestamp 10 | , schedule_dt date 11 | , sent_ts timestamp 12 | , sender varchar2(20 char) 13 | , recipient varchar2(20 char) 14 | , subject varchar2(4000) -- for mms 15 | , message varchar2(4000) 16 | , media_file varchar2(4000) -- for mms 17 | , voice_lang varchar2(100 char) -- for voice: e.g. en-us, en-au, en-gb 18 | , voice_gender varchar2(6 char) -- for voice: female or male 19 | , country varchar2(10 char) 20 | , reply_email varchar2(255 char) 21 | , custom_string varchar2(4000) 22 | , clicksend_messageid varchar2(4000) 23 | , clicksend_result varchar2(100 char) 24 | , clicksend_errortext varchar2(4000) 25 | , clicksend_cost number 26 | , clicksend_response varchar2(4000) 27 | ); 28 | 29 | -- table to store the clicksend parameters for this system 30 | create table clicksend_settings 31 | ( setting_name varchar2(100) not null 32 | , setting_value varchar2(4000) 33 | , constraint clicksend_settings_pk primary key (setting_name) 34 | ); -------------------------------------------------------------------------------- /create_types.sql: -------------------------------------------------------------------------------- 1 | prompt create_types.sql 2 | -- types used by clicksend 0.2 3 | 4 | create type t_clicksend_msg is object 5 | ( message_type varchar2(20) -- sms, mms, voice 6 | , requested_ts timestamp 7 | , schedule_dt date 8 | , sender varchar2(20) 9 | , recipient varchar2(20) 10 | , subject varchar2(4000) -- for mms 11 | , message varchar2(4000) 12 | , media_file varchar2(4000) -- for mms 13 | , voice_lang varchar2(100) -- for voice: e.g. en-us, en-au, en-gb 14 | , voice_gender varchar2(6) -- for voice: female or male 15 | , country varchar2(10 char) 16 | , reply_email varchar2(255 char) 17 | , custom_string varchar2(4000) 18 | ); 19 | / 20 | 21 | create type t_clicksend_lang is object 22 | (lang_code varchar2(10) 23 | ,country_desc varchar2(100) 24 | ,female varchar2(1) 25 | ,male varchar2(1) 26 | ); 27 | / 28 | 29 | create type t_clicksend_lang_arr is table of t_clicksend_lang; 30 | 31 | create type t_clicksend_country is object 32 | (country_code varchar2(10) 33 | ,country_name varchar2(100) 34 | ); 35 | / 36 | 37 | create type t_clicksend_country_arr is table of t_clicksend_country; 38 | 39 | create type t_clicksend_sms_history is object 40 | (event_dt date 41 | ,mobile varchar2(20) 42 | ,message varchar2(4000) 43 | ,status varchar2(100) 44 | ,sender varchar2(100) 45 | ,schedule_dt date 46 | ,status_code varchar2(100) 47 | ,status_text varchar2(4000) 48 | ,error_code varchar2(100) 49 | ,error_text varchar2(4000) 50 | ,message_id varchar2(4000) 51 | ,message_parts number 52 | ,message_price number 53 | ,reply_email varchar2(255) 54 | ,custom_string varchar2(4000) 55 | ,subaccount_id number 56 | ,country varchar2(10) 57 | ,carrier varchar2(100) 58 | ); 59 | / 60 | 61 | create type t_clicksend_sms_history_arr is table of t_clicksend_sms_history; 62 | -------------------------------------------------------------------------------- /examples.sql: -------------------------------------------------------------------------------- 1 | -- WARNING: this is just a bunch of examples without explanation and not necessarily useful to you... 2 | 3 | -- For proper documentation and examples refer to the WIKI: 4 | -- https://github.com/jeffreykemp/clicksend-plsql-api/wiki 5 | 6 | begin 7 | clicksend_pkg.init 8 | (p_clicksend_username => site_parameter.get_value('SMS_USERNAME') 9 | ,p_clicksend_secret_key => site_parameter.get_value('SMS_SECRET_KEY') 10 | ,p_api_url => 'http://api.yourproxy.com/clicksend/v3/' 11 | ); 12 | end; 13 | / 14 | 15 | begin 16 | clicksend_pkg.init(p_voice_preamble => ',,,,,'); 17 | end; 18 | / 19 | 20 | exec clicksend_pkg.create_queue; 21 | 22 | exec clicksend_pkg.create_job; 23 | 24 | exec clicksend_pkg.create_purge_job; 25 | 26 | begin 27 | clicksend_pkg.send_sms 28 | (p_sender => 'tester' 29 | ,p_mobile => '+61411111111' -- +61411111111 is a free test number, no msg will be sent or charged 30 | ,p_message => 'testing ' || to_char(systimestamp,'DD/MM/YYYY HH24:MI:SS.FF') 31 | ); 32 | clicksend_pkg.push_queue; 33 | commit; 34 | end; 35 | / 36 | 37 | begin 38 | clicksend_pkg.send_mms 39 | (p_sender => 'tester' 40 | ,p_mobile => '+61411111111' -- +61411111111 is a free test number, no msg will be sent or charged 41 | ,p_subject => 'testing mms' 42 | ,p_message => 'testing ' || to_char(systimestamp,'DD/MM/YYYY HH24:MI:SS.FF') 43 | ,p_media_file_url => 'https://s3-ap-southeast-2.amazonaws.com/jk64/jk64logo.jpg' 44 | ); 45 | clicksend_pkg.push_queue; 46 | commit; 47 | end; 48 | / 49 | 50 | begin 51 | clicksend_pkg.send_voice 52 | (p_phone_no => '+61408388532' -- +61411111111 is a free test number, no msg will be sent or charged 53 | ,p_message => 'Hello. This message was sent on ' 54 | || to_char(systimestamp,'fmDay DD Month YYYY "at" HH:MI am, SS "seconds"') 55 | || '.' 56 | ,p_voice_lang => 'en-gb' 57 | ,p_voice_gender => 'female' 58 | ,p_schedule_dt => sysdate 59 | ); 60 | clicksend_pkg.push_queue; 61 | commit; 62 | end; 63 | / 64 | 65 | select clicksend_pkg.get_account_details from dual; 66 | 67 | select clicksend_pkg.get_credit_balance from dual; 68 | 69 | select * from table(clicksend_pkg.get_languages); 70 | 71 | select * from table(clicksend_pkg.get_countries); 72 | 73 | select * from table(clicksend_pkg.get_sms_history(sysdate-100,sysdate)); 74 | 75 | exec clicksend_pkg.drop_job; 76 | 77 | exec clicksend_pkg.drop_purge_job; 78 | 79 | exec clicksend_pkg.drop_queue; 80 | -------------------------------------------------------------------------------- /grants.sql: -------------------------------------------------------------------------------- 1 | -- grants required for clicksend_pkg 2 | undef myschema 3 | 4 | accept myschema prompt 'Enter the schema in which you will install clicksend:' 5 | 6 | grant create table to &&myschema; 7 | grant create job to &&myschema; 8 | grant create procedure to &&myschema; 9 | grant create type to &&myschema; 10 | 11 | grant execute on sys.dbms_aq to &&myschema; 12 | grant execute on sys.dbms_aqadm to &&myschema; 13 | grant execute on sys.dbms_job to &&myschema; 14 | grant execute on sys.dbms_scheduler to &&myschema; 15 | grant execute on sys.utl_http to &&myschema; 16 | -------------------------------------------------------------------------------- /install.sql: -------------------------------------------------------------------------------- 1 | prompt install.sql 2 | prompt clicksend v0.2 3 | -- run this script in the schema in which you wish the objects to be installed. 4 | 5 | @create_tables.sql 6 | @create_types.sql 7 | @clicksend_pkg.pks 8 | @clicksend_pkg.pkb 9 | 10 | prompt create queue 11 | begin clicksend_pkg.create_queue; end; 12 | / 13 | 14 | prompt create scheduler jobs 15 | begin clicksend_pkg.create_job; end; 16 | / 17 | 18 | begin clicksend_pkg.create_purge_job; end; 19 | / 20 | 21 | prompt attempt to recompile any invalid objects 22 | begin dbms_utility.compile_schema(user,false); end; 23 | / 24 | 25 | prompt update api_version 26 | merge into clicksend_settings t 27 | using (select 'api_version' as nm, '0.2' as val from dual) s 28 | on (t.setting_name = s.nm) 29 | when matched then update set setting_value = s.val 30 | when not matched then insert (setting_name, setting_value) 31 | values (s.nm, s.val); 32 | 33 | commit; 34 | 35 | set feedback off heading off 36 | 37 | prompt list clicksend objects 38 | select object_type, object_name, status from user_objects where object_name like '%clicksend%' order by object_type, object_name; 39 | 40 | prompt list clicksend queues 41 | select name, queue_table from user_queues where name like '%clicksend%' order by name; 42 | 43 | prompt list clicksend scheduler jobs 44 | select job_name, 'enabled='||enabled status, job_action, repeat_interval from user_scheduler_jobs where job_name like '%clicksend%'; 45 | 46 | prompt finished. 47 | set feedback on heading on -------------------------------------------------------------------------------- /install_with_logger.sql: -------------------------------------------------------------------------------- 1 | prompt install.sql 2 | prompt clicksend v0.2 3 | -- run this script in the schema in which you wish the objects to be installed. 4 | 5 | @create_tables.sql 6 | @create_types.sql 7 | @clicksend_pkg.pks 8 | @clicksend_pkg_with_logger.pkb 9 | 10 | prompt create queue 11 | begin clicksend_pkg.create_queue; end; 12 | / 13 | 14 | prompt create scheduler jobs 15 | begin clicksend_pkg.create_job; end; 16 | / 17 | 18 | begin clicksend_pkg.create_purge_job; end; 19 | / 20 | 21 | prompt attempt to recompile any invalid objects 22 | begin dbms_utility.compile_schema(user,false); end; 23 | / 24 | 25 | prompt update api_version 26 | merge into clicksend_settings t 27 | using (select 'api_version' as nm, '0.2' as val from dual) s 28 | on (t.setting_name = s.nm) 29 | when matched then update set setting_value = s.val 30 | when not matched then insert (setting_name, setting_value) 31 | values (s.nm, s.val); 32 | 33 | commit; 34 | 35 | begin logger.log_permanent('Clicksend PL/SQL API installed v0.2', 'clicksend'); end; 36 | / 37 | 38 | set feedback off heading off 39 | 40 | prompt list clicksend objects 41 | select object_type, object_name, status from user_objects where object_name like '%clicksend%' order by object_type, object_name; 42 | 43 | prompt list clicksend queues 44 | select name, queue_table from user_queues where name like '%clicksend%' order by name; 45 | 46 | prompt list clicksend scheduler jobs 47 | select job_name, 'enabled='||enabled status, job_action, repeat_interval from user_scheduler_jobs where job_name like '%clicksend%'; 48 | 49 | prompt finished. 50 | set feedback on heading on -------------------------------------------------------------------------------- /uninstall.sql: -------------------------------------------------------------------------------- 1 | prompt uninstall.sql 2 | -- v0.1 3 | 4 | prompt drop job (process queue) 5 | begin dbms_scheduler.stop_job ('clicksend_process_queue'); exception when others then if sqlcode not in (-27366,-27475) then raise; end if; end; 6 | / 7 | begin dbms_scheduler.drop_job('clicksend_process_queue'); exception when others then if sqlcode not in (-27366,-27475) then raise; end if; end; 8 | / 9 | 10 | prompt drop job (purge logs) 11 | begin dbms_scheduler.stop_job ('clicksend_purge_logs'); exception when others then if sqlcode not in (-27366,-27475) then raise; end if; end; 12 | / 13 | begin dbms_scheduler.drop_job('clicksend_purge_logs'); exception when others then if sqlcode not in (-27366,-27475) then raise; end if; end; 14 | / 15 | 16 | prompt drop queue 17 | begin dbms_aqadm.stop_queue (user||'.clicksend_queue'); exception when others then if sqlcode!=-24010 then raise; end if; end; 18 | / 19 | begin dbms_aqadm.drop_queue (user||'.clicksend_queue'); exception when others then if sqlcode!=-24010 then raise; end if; end; 20 | / 21 | begin dbms_aqadm.drop_queue_table (user||'.clicksend_queue_tab'); exception when others then if sqlcode not in (-24010,-24002) then raise; end if; end; 22 | / 23 | 24 | prompt drop tables 25 | begin execute immediate 'drop table clicksend_msg_log'; exception when others then if sqlcode!=-942 then raise; end if; end; 26 | / 27 | begin execute immediate 'drop table clicksend_settings'; exception when others then if sqlcode!=-942 then raise; end if; end; 28 | / 29 | 30 | prompt drop types 31 | begin execute immediate 'drop type t_clicksend_msg'; exception when others then if sqlcode!=-4043 then raise; end if; end; 32 | / 33 | begin execute immediate 'drop type t_clicksend_lang_arr'; exception when others then if sqlcode!=-4043 then raise; end if; end; 34 | / 35 | begin execute immediate 'drop type t_clicksend_lang'; exception when others then if sqlcode!=-4043 then raise; end if; end; 36 | / 37 | begin execute immediate 'drop type t_clicksend_country_arr'; exception when others then if sqlcode!=-4043 then raise; end if; end; 38 | / 39 | begin execute immediate 'drop type t_clicksend_country'; exception when others then if sqlcode!=-4043 then raise; end if; end; 40 | / 41 | begin execute immediate 'drop type t_clicksend_sms_history_arr'; exception when others then if sqlcode!=-4043 then raise; end if; end; 42 | / 43 | begin execute immediate 'drop type t_clicksend_sms_history'; exception when others then if sqlcode!=-4043 then raise; end if; end; 44 | / 45 | 46 | prompt drop package 47 | begin execute immediate 'drop package clicksend_pkg'; exception when others then if sqlcode!=-4043 then raise; end if; end; 48 | / 49 | 50 | prompt finished. --------------------------------------------------------------------------------