├── README.md ├── docs ├── Certificate_of_the_remote_server_does_not_match_the_target_address.md ├── Create_oracle_wallet.md └── img │ ├── api_key.png │ ├── authenticate_email.png │ ├── final_email.png │ ├── get_certificates1.png │ ├── get_certificates2.png │ ├── get_certificates3.png │ ├── get_certificates4.png │ ├── id_common_name.png │ ├── template_gui.png │ └── template_substitutions.png ├── fabe website 04.08.2019 2.sql ├── fabe website 04.08.2019.sql ├── license └── source ├── install.sql ├── packages ├── mailchimp_pkg.pkb └── mailchimp_pkg.pks ├── tables ├── campaign_history_typ_tbl.sql ├── mailchimp_env_var.sql ├── merge_field_typ_tbl.sql └── subscriber_typ_tbl.sql ├── types ├── campaign_history_typ.sql ├── campaign_history_typ_set.sql ├── merge_field_typ.sql ├── merge_field_typ_set.sql ├── subscriber_typ.sql └── subscriber_typ_set.sql └── uninstall.sql /README.md: -------------------------------------------------------------------------------- 1 | # MailChimp PL/SQL API 2 | Interact with the MailChimp API using PL/SQL. 3 | 4 | ### Benefits of using MailChimp 5 | Using MailChimp has many advantages: 6 | - Deliverabity & Reputation : 7 | MailChimp makes it easy for you to craft mail that complies will all the highest standards of the [CAN-SPAM](https://mailchimp.com/help/anti-spam-requirements-for-email/) act and signals to email providers that your mail is legitimate. 8 | - Free (for my purposes): 9 | At the time of this writing, if you have fewer than 2,000 subscribers and send fewer than 12,000 emails / month, there's no expiring trial, contract or credit card required. Your emails will have a small amount of MailChimp branding at the bottom (see screenshot at the end of this post) but nothing that offends me. Getting rid of this branding would cost me around $10/month. 10 | - Easily craft handsome & robust email templates: 11 | Worrying about how your email will render across different email clients is a drag. MailChimp defaults are certainly better than anything I'm going to design myself. 12 | - Sophisticated reporting: 13 | Access in-depth stats on open-rate, unsubscribe-rate, etc to better understand and serve your intended audience. 14 | - Easy set-up and maintenance: 15 | Obviously this path obviates the need to setup and maintain your own email server. 16 | 17 | 18 | 19 | # Prerequisites 20 | ## Enable your database to talk to MailChimp 21 | ### Import the necessary certificates 22 | You'll need to import the certificate chain (not the end certificate) to your Oracle Wallet for the website us[XX].api.mailchimp.com (e.g. us18.api.mailchimp.com). 23 | 24 | Proof that you've successfully configured your database to talk to the MailChimp API is to be able to run the following without error: 25 | ``` 26 | select apex_web_service.make_rest_request( 27 | p_url => 'https://us18.api.mailchimp.com' 28 | , p_http_method => 'GET' 29 | , p_wallet_path => 'file:[path to your oracle wallet]' 30 | ) from dual; 31 | 32 | ``` 33 | If you get the error 'ORA-29024: Certificate validation failure', it must be because you have not imported the certificate chain referenced above to your linked oracle wallet. See my notes on [how I configured my Oracle Wallet](docs/Create_oracle_wallet.md). 34 | 35 | If you get the error 'ORA-24263: Certificate of the remote server does not match the target address.', it must mean that you are on a 12.2 database (or higher) and you need to add a parameter to your request: 36 | ``` 37 | select apex_web_service.make_rest_request( 38 | p_url => 'https://us18.api.mailchimp.com' 39 | , p_http_method => 'GET' 40 | , p_wallet_path => 'file:[path to your oracle wallet]' 41 | , p_https_host => 'wildcardsan2.mailchimp.com' 42 | ) from dual; 43 | ``` 44 | The 'HTTPS Host' refers to the 'Common Name' of the URL you are trying to reach and must now be specified when your API is employing a 'multiple domain certificate'. See my notes on [solving the ORA-24263 error](docs/Certificate_of_the_remote_server_does_not_match_the_target_address.md). 45 | 46 | ## Compatibility 47 | 48 | The json functions I leverage require at least a 12.2 database and APEX 5.1.4. It should, nonetheless, be simple to adapt them for a lower environment. 49 | 50 | For example: 51 | ``` 52 | l_list_id := json_value(l_response, '$.id'); 53 | ``` 54 | The above syntax requires a 12.2 database. It could however be replaced with the following in a 12.1 database: 55 | ``` 56 | select json_value(l_response, '$.id') 57 | into l_list_id 58 | from dual; 59 | ``` 60 | 61 | 62 | ## Logger 63 | 64 | It would, of course, be perfectly possible to write this PL/SQL package without using Logger. Nonetheless, I am unashamedly dependent on it and would encourage anyone to give it a try before removing all the logger code that I've written. [Installation is simple and the documentation is thorough.](https://github.com/OraOpenSource/Logger) 65 | 66 | # Using the MailChimp API through PL/SQL 67 | ## Installation 68 | 69 | There is not much to be installed just [1 package, 6 types and 3 tables](source/install.sql). 70 | 71 | 72 | ## Create a MailChimp account 73 | Your 1st step should be to create a free account on [Mailchimp](https://mailchimp.com/). 74 | ### Get your API Key 75 | You can create and manage your API keys in the account section of MailChimp: 76 |

77 |
78 | MailChimp API Keys 79 |
80 |
81 |

82 | Note: API keys are sensitive data. Keep yours secure, the one featured in the picture above is no longer a valid one. 83 | 84 | ### Determine your URL Prefix 85 | You'll need to determine your 'URL prefix', as I'm calling it, to use the MailChimp API. You are assigned one when you create an account. I know that I'm 'us18' looking at the URL of MailChimp as a logged-in user. There are probably many ways to determine this. 86 | 87 | ### Authenticate your email with MailChimp 88 | While you're there, be sure to authenticate the email you intend to have as your 'From' email with MailChimp: 89 |

90 |
91 | Authenticate your email 92 |
93 |
94 |

95 | 96 | ### Populate values in package 97 | With your URL prefix and API key, you can now begin populating the global variables listed at the top of the [mailchimp_pkg body](source/packages/mailchimp_pkg.pkb). 98 | ``` 99 | g_url_prefix constant varchar2(100):= 'https://usXX.api.mailchimp.com/3.0/'; 100 | g_password constant varchar2(50) := '[your MailChimp API Key]'; 101 | g_wallet_path constant varchar2(100):= 'file:[path to your Oracle Wallet]'; 102 | g_https_host constant varchar2(100):= 'wildcardsan2.mailchimp.com'; 103 | g_company_name constant varchar2(100):= '[Your organization]'; 104 | g_reply_to constant varchar2(100):= '[The email you athenticated with MailChimp]'; 105 | g_from_name constant varchar2(100):= '[Your name]'; 106 | ... 107 | ``` 108 | 109 | 110 | ## Create an email list 111 | 112 | You're now ready to start using the API. The 1st step is to create a 'list', where you'll store all the recipients of the email you're trying to send. The only 2 inputs are the name you'll give the list and a short statement that will be included in the email that will explain to recipients how they got on this email list. For illustrative purposes, I'll use as my example: Composing an email to people who have elected to stay up-to-date on the comments of a blog posting. 113 | ``` 114 | declare 115 | l_list_id varchar2(100); 116 | begin 117 | mailchimp_pkg.create_list( p_list_name => 'Blog commenters', 118 | p_permission_reminder => 'You signed up to be updated when new comments are posted.', 119 | p_list_id => l_list_id); 120 | 121 | dbms_output.put_line('Your newly generated list_id is :'||l_list_id); 122 | end; 123 | ``` 124 | ### Add subscribers 125 | Your list generated, you can now add however many recipients you choose. Below, I illustrate adding myself to my recipient list: 126 | ``` 127 | declare 128 | l_success boolean; 129 | begin 130 | mailchimp_pkg.add_subscriber ( p_list_id => '[you list_id]', 131 | p_email => 'hhudson@insum.ca', 132 | p_fname => 'Hayden', 133 | p_lname => 'Hudson', 134 | p_success => l_success); 135 | if l_success then 136 | dbms_output.put_line('The operation was successful.'); 137 | else 138 | dbms_output.put_line('Something went wrong. Check the logs.'); 139 | end if; 140 | end; 141 | ``` 142 | ### View your subscribers 143 | If at any point you lose track of who you've added to your list, you can query it as follows: 144 | ``` 145 | SELECT * 146 | FROM TABLE(blog_mailchimp_pkg.get_list_of_subscribers ( p_list_id => '[you list_id]')); 147 | ``` 148 | ## Prepare your email 149 | ## Create an email template 150 | Beautiful templates is one of the main reasons why people use MailChimp. Below, I explain 2 options for creating templates. I have a preference for the 2nd one. 151 | 152 | 153 | ### Option 1: Create template with API 154 | If you're not afraid of HTML and CSS, you can craft your own email template and pass it to MailChimp using their API: 155 | ``` 156 | declare 157 | l_template_id integer; 158 | begin 159 | mailchimp_pkg.create_template (p_template_name => 'Your template name', 160 | p_html => 'This is a really basic email.', 161 | p_template_id => l_template_id); 162 | dbms_output.put_line('Your newly generated template_id is :'||l_template_id); 163 | end; 164 | ``` 165 | ### Option 2: Create template with MailChimp GUI 166 | Spare yourself the trouble of having to worry about your email's HTML and CSS. Use MailChimp's easy GUI to assemble a handsome and performant template. Simply log in and visit the 'Templates' tab to get started. Take not of the 'template_id' in the URL - for eg '46701' in the screenshot below. 167 |

168 |
169 | MailChimp GUI 170 |
171 |
172 |

173 | 174 | ## Pass data into your template with API 175 | As a best practice, I recommend keep your templates fairly generic to maximize for general use. The real content of your emails can be passed in by one of the 2 methods (and there may be more) described below: 176 | ### Option 1: Update entire template html 177 | If you favored Option 1 above, you may also like the option to update the entire template's HTML: 178 | ``` 179 | declare 180 | l_success boolean; 181 | begin 182 | mailchimp_pkg.update_template (p_template_id => '[you template_id]', 183 | p_html => 'This is nothing fancy.', 184 | p_success => l_success); 185 | if l_success then 186 | dbms_output.put_line('The operation was successful.'); 187 | else 188 | dbms_output.put_line('Something went wrong. Check the logs.'); 189 | end if; 190 | end; 191 | ``` 192 | ### Option 2: Use Merge Fields 193 | I favor using 'Merge Fields', myself. 194 | #### Add Merge Field(s) to your template 195 | Step 1 is to create your own custom Merge Fields. Start by simply design your own 'tags', using the correct *|SYNTAX|* directly into your MailChimp template (they must be under 10 characters in length): 196 |

197 |
198 | Template Merge Fields 199 |
200 |
201 |

202 | 203 | #### Add Merge Field(s) to your list 204 | Step 2 is to then formally add those same 'tags' to your previously-created 'list' 205 | ``` 206 | declare 207 | l_merge_id integer; 208 | l_tag varchar2(100); 209 | begin 210 | mailchimp_pkg.create_merge_field( p_list_id => '[you list_id]', 211 | p_merge_field_tag => '[a tag for your merge field]', 212 | p_merge_field_name => '[a more descriptive name]' 213 | p_merge_id => l_merge_id, 214 | p_tag => l_tag); 215 | dbms_output.put_line('Your newly generated merge_id :'||l_merge_id); 216 | dbms_output.put_line('The associated tag is :'||l_tag); 217 | end; 218 | ``` 219 | Note: Tags cannot be more than 10 characters. For the purposes of my example, the values that I’d pass into p_merge_field_tag are POST_NAME, COMMENT AND BLOGLINK (see template picture, above). 220 | #### Assign value(s) to your Merge Field(s) 221 | Finally, you assign the values you wish to pass into your email with the following: 222 | ``` 223 | declare 224 | l_success boolean; 225 | begin 226 | mailchimp_pkg.update_merge_field (p_list_id => '[you list_id]', 227 | p_merge_field_tag => '[the tag for your merge field]', 228 | p_merge_value => 'Nice post!', 229 | p_success => l_success); 230 | if l_success then 231 | dbms_output.put_line('The operation was successful.'); 232 | else 233 | dbms_output.put_line('Something went wrong. Check the logs.'); 234 | end if; 235 | end; 236 | ``` 237 | #### Review Merge Fields 238 | If ever you lose track of which tags are already assigned to your 'list', you can query them with the following: 239 | ``` 240 | SELECT * 241 | FROM TABLE(mailchimp_pkg.get_list_of_merge_fields(p_list_id => '[you list_id]')); 242 | ``` 243 | ## Send your email 244 | ### Generate your 'campaign' url 245 | Almost there! MailChimp refers to all emails as 'campaigns'. Generate the URL for your intended email with the following API: 246 | ``` 247 | declare 248 | l_send_url varchar2(100); 249 | begin 250 | mailchimp_pkg.create_campaign ( p_list_id =>'[you list_id]', 251 | p_subject_line => 'New blog comment', 252 | p_title => 'Blog comment email', 253 | p_template_id => '[you template_id]', 254 | p_send_url => l_send_url); 255 | dbms_output.put_line('Your email is ready to send with the following url :'l_send_url); 256 | end; 257 | ``` 258 | ### Send your campaign 259 | Take that URL and simply plug it into the following: 260 | ``` 261 | declare 262 | l_success boolean; 263 | begin 264 | mailchimp_pkg.send_campaign (p_send_url => '[your campaign send_url]', 265 | p_success => l_success); 266 | if l_success then 267 | dbms_output.put_line('The operation was successful.'); 268 | else 269 | dbms_output.put_line('Something went wrong. Check the logs.'); 270 | end if; 271 | end; 272 | ``` 273 | By way of illustration, below is an example email that was sent using the above-described steps: 274 |

275 |
276 | Final Email 277 |
278 |
279 |

280 | 281 | ## Review historical campaigns 282 | MailChimp's reporting capabilities are an important driving factor for its adoption. I have pulled in several (but by no means all) of MailChimp's reporting stats in the following query: 283 | ``` 284 | SELECT * 285 | FROM TABLE(blog_mailchimp_pkg.get_campaign_history) 286 | WHERE CAMPAIGN_ID IS NOT NULL 287 | ORDER BY SEND_TIME 288 | ``` 289 | 290 | 291 | -------------------------------------------------------------------------------- /docs/Certificate_of_the_remote_server_does_not_match_the_target_address.md: -------------------------------------------------------------------------------- 1 | # ORA-29024: Certificate of the remote server does not match the target address 2 | 3 | Does your apex_web_service.make_rest_request generate the following error? 4 | ``` 5 | ORA-24263: Certificate of the remote server does not match the target address. 6 | ``` 7 | This error must be because you are on a 12.2 or higher database and you need to an ['HTTPS_HOST' parameter to your request](http://www.orafaq.com/node/3079). For example: 8 | ``` 9 | select apex_web_service.make_rest_request( 10 | p_url => 'https://us18.api.mailchimp.com' 11 | , p_http_method => 'GET' 12 | , p_wallet_path => 'file:/home/oracle/orapki_wallet' 13 | , p_https_host => 'wildcardsan2.mailchimp.com' 14 | ) from dual; 15 | ``` 16 | Notice how different the p_url is from the p_https_host? This shows that MailChimp is using a 'multiple domain certificate'. Such a certificate now needs special handling in an Oracle environment. 17 | 18 | ## How to identify the https_host 19 | 20 | ### Visit a URL for your API 21 | 22 | I recommend using Firefox for its ease-of-use. For this example, I visited https://us18.api.mailchimp.com/3.0/: 23 |

24 |
25 | Visit website in Firefox 26 |
27 |
28 |

29 | 30 | ### Click on the 'information' icon in the URL bar 31 | Then click on the right-arrow to access 'More information'. 32 |

33 |
34 | Click on information icon 35 |
36 |
37 |

38 | 39 | ### Visit the 'Security' tab 40 | Click on 'View Certificate' 41 |

42 |
43 | Navigate to security tab 44 |
45 |
46 |

47 | 48 | ### Find the Common Name 49 | You can view the 'Common Name' under the 'General' tab: 50 |

51 |
52 | Identify website common name 53 |
54 |
55 |

56 | This 'Common Name' is your 'https host'. -------------------------------------------------------------------------------- /docs/Create_oracle_wallet.md: -------------------------------------------------------------------------------- 1 | # How to setup your Oracle Wallet to connect to the MailChimp API 2 | 3 | ## Download the API's certificate chain 4 | 5 | ### Visit a URL for your API 6 | 7 | I recommend using Firefox for its ease-of-use. I visited https://us18.api.mailchimp.com/3.0/ somewhat arbitrarily. MailChimp may assign you a different API URL but its almost certain the certificates would be the same, regardless: 8 |

9 |
10 | Visit website in Firefox 11 |
12 |
13 |

14 | 15 | ### Click on the 'information' icon in the URL bar 16 | Then click on the right-arrow to access 'More information'. 17 |

18 |
19 | Click on information icon 20 |
21 |
22 |

23 | 24 | ### Visit the 'Security' tab 25 | Click on 'View Certificate' 26 |

27 |
28 | Navigate to security tab 29 |
30 |
31 |

32 | 33 | ### You can export the certificates from the 'Details' tab 34 | For the certificate chain, you want to export the top 2 certificates. In this case, that describes 'DigiCert Global Root CA' and 'DigiCert ECC Secure Server CA'. Don't export the wildcard certificate, [apparently](https://stackoverflow.com/questions/19380116/using-utl-http-wallets-on-12c-certificate-validation-failure). 35 |

36 |
37 | Export the certificate chain 38 |
39 |
40 |

41 | 42 | ## Setup your Oracle Wallet 43 | 44 | You can reuse an existing wallet but there's no down-side to starting a new one. I favor managing my wallets with the orapki command-line utility. 45 | 46 | ### Create wallet 47 | ``` 48 | [oracle@server]$ orapki wallet create -wallet /home/oracle/orapki_wallet -pwd Oradoc_db1 -auto_login 49 | Oracle PKI Tool : Version 12.2.0.1.0 50 | Copyright (c) 2004, 2016, Oracle and/or its affiliates. All rights reserved. 51 | 52 | Operation is successfully completed. 53 | ``` 54 | ### Add your certificates 55 | After moving your previously download certificates to your server, you can add them to your wallet with the orapki utility: 56 | ``` 57 | [oracle@server]$ orapki wallet add -wallet /home/oracle/orapki_wallet/ -cert DigiCertGlobalRootCA.crt -trusted_cert -pwd Oradoc_db1 58 | Oracle PKI Tool : Version 12.2.0.1.0 59 | Copyright (c) 2004, 2016, Oracle and/or its affiliates. All rights reserved. 60 | 61 | Operation is successfully completed. 62 | 63 | [oracle@server]$ orapki wallet add -wallet /home/oracle/orapki_wallet/ -cert DigiCertECCSecureServerCA.crt -trusted_cert -pwd Oradoc_db1 64 | Oracle PKI Tool : Version 12.2.0.1.0 65 | Copyright (c) 2004, 2016, Oracle and/or its affiliates. All rights reserved. 66 | 67 | Operation is successfully completed. 68 | ``` 69 | Note: The above was performed on a 12.2 Oracle Datbase. On as 12.1 Database I got an 'PKI-04001: Invalid Certificate' error with the DigiCertECCSecureServerCA.crt certificate. Ultimately, it didn't matter, the wallet worked fine with only the root certificate. 70 | 71 | ### Inspect your wallet's contents 72 | You can validate the contents of your wallet with the 'display' command: 73 | ``` 74 | [oracle@server]$ orapki wallet display -wallet /home/oracle/orapki_wallet/ 75 | Oracle PKI Tool : Version 12.2.0.1.0 76 | Copyright (c) 2004, 2016, Oracle and/or its affiliates. All rights reserved. 77 | 78 | Requested Certificates: 79 | User Certificates: 80 | Trusted Certificates: 81 | Subject: CN=DigiCert ECC Secure Server CA,O=DigiCert Inc,C=US 82 | Subject: CN=DigiCert Global Root CA,OU=www.digicert.com,O=DigiCert Inc,C=US 83 | 84 | ``` 85 | 86 | ## Attempt Rest Request 87 | 88 | If all the necessary certificates are present, the below Rest Request (replacing the p_wallet_path to match your configuration) should not give you a 'ORA-29024: Certificate validation failure': 89 | ``` 90 | select apex_web_service.make_rest_request( 91 | p_url => 'https://us18.api.mailchimp.com', 92 | p_http_method => 'GET', 93 | p_wallet_path => 'file:/home/oracle/orapki_wallet' 94 | ) from dual; 95 | ``` 96 | If you get the error 'ORA-24263: Certificate of the remote server does not match the target address.', it must mean that you are on a 12.2 database (or higher) and you need to add a parameter to your request: 97 | ``` 98 | select apex_web_service.make_rest_request( 99 | p_url => 'https://us18.api.mailchimp.com' 100 | , p_http_method => 'GET' 101 | , p_wallet_path => 'file:/home/oracle/orapki_wallet' 102 | , p_https_host => 'wildcardsan2.mailchimp.com' 103 | ) from dual; 104 | ``` 105 | The 'HTTPS Host' refers to the 'Common Name' of the URL you are trying to reach and must now be specified when it does not match the destination URL. See my notes on [solving the ORA-24263 error](Certificate_of_the_remote_server_does_not_match_the_target_address.md). -------------------------------------------------------------------------------- /docs/img/api_key.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/api_key.png -------------------------------------------------------------------------------- /docs/img/authenticate_email.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/authenticate_email.png -------------------------------------------------------------------------------- /docs/img/final_email.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/final_email.png -------------------------------------------------------------------------------- /docs/img/get_certificates1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/get_certificates1.png -------------------------------------------------------------------------------- /docs/img/get_certificates2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/get_certificates2.png -------------------------------------------------------------------------------- /docs/img/get_certificates3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/get_certificates3.png -------------------------------------------------------------------------------- /docs/img/get_certificates4.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/get_certificates4.png -------------------------------------------------------------------------------- /docs/img/id_common_name.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/id_common_name.png -------------------------------------------------------------------------------- /docs/img/template_gui.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/template_gui.png -------------------------------------------------------------------------------- /docs/img/template_substitutions.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hhudson/mailchimp_plsql_api/aae2bba9296230585fdd488198c9752dac36f149/docs/img/template_substitutions.png -------------------------------------------------------------------------------- /fabe website 04.08.2019 2.sql: -------------------------------------------------------------------------------- 1 | set serveroutput on 2 | declare 3 | l_listid varchar2(50) := '5da68a7259'; 4 | l_myemail varchar2(50) := 'hhudson@fab.earth'; 5 | l_firstname varchar2(50) := 'Holden'; 6 | l_lastname varchar2(50) := 'Caulfield'; 7 | l_add_sub boolean; 8 | l_subject_line varchar2(500) := 'Thanks for creating another action'; 9 | l_templateid number := 67935; 10 | l_campaignid varchar2(50); 11 | l_send_url varchar2(500); 12 | l_ready boolean; 13 | l_sent boolean; 14 | l_removed boolean; 15 | begin 16 | mailchimp_pkg.add_subscriber (p_list_id => l_listid, 17 | p_email => l_myemail, 18 | p_fname => l_firstname, 19 | p_lname => l_lastname, 20 | p_success => l_add_sub); 21 | if l_add_sub then 22 | dbms_output.put_line('added subscriber'); 23 | mailchimp_pkg.create_campaign ( p_list_id => l_listid, 24 | p_subject_line => l_subject_line, 25 | p_title => l_subject_line, 26 | p_template_id => l_templateid, 27 | p_campaign_id => l_campaignid, 28 | p_send_url => l_send_url); 29 | dbms_output.put_line('l_campaignid :'||l_campaignid); 30 | dbms_output.put_line('l_send_url :'||l_send_url); 31 | mailchimp_pkg.send_campaign_checklist (p_campaign_id => l_campaignid, 32 | p_ready => l_ready); 33 | 34 | if l_ready then 35 | dbms_output.put_line('campaign ready'); 36 | mailchimp_pkg.send_campaign (p_send_url => l_send_url, 37 | p_success => l_sent); 38 | if l_sent then 39 | dbms_output.put_line('sent'); 40 | mailchimp_pkg.remove_subscriber ( p_list_id => l_listid, 41 | p_email => l_myemail, 42 | p_success => l_removed); 43 | if l_removed then 44 | dbms_output.put_line('removed subscriber'); 45 | else 46 | dbms_output.put_line('failed to remove subscriber'); 47 | end if; 48 | else 49 | dbms_output.put_line('failed to send'); 50 | end if; 51 | else 52 | dbms_output.put_line('campaign not ready'); 53 | end if; 54 | else 55 | dbms_output.put_line('failed to add subscriber'); 56 | end if; 57 | end; -------------------------------------------------------------------------------- /fabe website 04.08.2019.sql: -------------------------------------------------------------------------------- 1 | set serveroutput on 2 | declare 3 | l_listid varchar2(50); 4 | begin 5 | l_listid := mailchimp_pkg.create_list (p_list_name => 'test list 04.08.2019', 6 | p_permission_reminder => 'you created an action'); 7 | dbms_output.put_line('list id: '||l_listid); --af6228aa95 8 | end; 9 | / 10 | declare 11 | l_listid varchar2(50) := 'af6228aa95'; 12 | l_add_sub boolean; 13 | begin 14 | mailchimp_pkg.add_subscriber ( p_list_id => l_listid, 15 | p_email => 'haydenhhudson@gmail.com', 16 | p_fname => 'Hayden', 17 | p_lname => 'Hudson', 18 | p_success => l_add_sub); 19 | if l_add_sub then 20 | dbms_output.put_line('added subscriber'); 21 | else 22 | dbms_output.put_line('failed to add subscriber'); 23 | end if; 24 | end; 25 | / 26 | declare 27 | l_listid varchar2(50) := 'af6228aa95'; 28 | l_templateid number := 67935; 29 | l_campaignid varchar2(50); 30 | l_url varchar2(500); 31 | begin 32 | mailchimp_pkg.create_campaign ( p_list_id => l_listid, 33 | p_subject_line => 'test email 04.08.2019', 34 | p_title => 'test email 04.08.2019', 35 | p_template_id => l_templateid, 36 | p_campaign_id => l_campaignid, 37 | p_send_url => l_url); 38 | 39 | dbms_output.put_line('l_campaignid :'||l_campaignid); 40 | dbms_output.put_line('l_url :'||l_url); 41 | /* 42 | l_campaignid :a487e527db 43 | l_url :https://us19.api.mailchimp.com/3.0/campaigns/a487e527db/actions/send 44 | */ 45 | end; 46 | / 47 | declare 48 | l_campaignid varchar2(50) := 'a487e527db'; 49 | l_ready boolean; 50 | begin 51 | mailchimp_pkg.send_campaign_checklist (p_campaign_id => l_campaignid, 52 | p_ready => l_ready); 53 | 54 | if l_ready then 55 | dbms_output.put_line('ready'); 56 | else 57 | dbms_output.put_line('not ready'); 58 | end if; 59 | end; 60 | / 61 | declare 62 | l_send_url varchar2(500) := 'https://us19.api.mailchimp.com/3.0/campaigns/a487e527db/actions/send'; 63 | l_success boolean; 64 | begin 65 | mailchimp_pkg.send_campaign (p_send_url => l_send_url, 66 | p_success => l_success); 67 | if l_success then 68 | dbms_output.put_line('sent'); 69 | else 70 | dbms_output.put_line('failed to send'); 71 | end if; 72 | end; 73 | -------------------------------------------------------------------------------- /license: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) Hayden Hudson 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 13 | all 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 21 | THE SOFTWARE. 22 | -------------------------------------------------------------------------------- /source/install.sql: -------------------------------------------------------------------------------- 1 | @types/subscriber_typ.sql; 2 | @types/subscriber_typ_set.sql; 3 | @tables/subscriber_typ_tbl.sql; 4 | @types/merge_field_typ.sql; 5 | @types/merge_field_typ_set.sql; 6 | @tables/merge_field_typ_tbl.sql; 7 | @types/campaign_history_typ.sql; 8 | @types/campaign_history_typ_set.sql; 9 | @tables/campaign_history_typ_tbl.sql; 10 | @tables/mailchimp_env_var.sql; 11 | set define off; 12 | @packages/mailchimp_pkg.pks; 13 | @packages/mailchimp_pkg.pkb; 14 | / 15 | 16 | -------------------------------------------------------------------------------- /source/packages/mailchimp_pkg.pkb: -------------------------------------------------------------------------------- 1 | create or replace package body mailchimp_pkg as 2 | 3 | gc_scope_prefix constant varchar2(31) := lower($$plsql_unit) || '.'; ----------------- necessary for the logger implementation 4 | g_url_prefix constant varchar2(100) := get_env_var (p_var_name => 'url_prefix'); --- your Mailchimp url prefix, in the format 'https://us[XX].api.mailchimp.com/3.0/' 5 | g_password constant varchar2(50) := get_env_var (p_var_name => 'api_key'); ------ this is your API Key (very sensitive - keep to yourself) 6 | g_wallet_path constant varchar2(100) := get_env_var (p_var_name => 'wallet_path'); -- the path on to your Oracle Wallet, syntax 'file:[path to your Oracle Wallet]' 7 | g_https_host constant varchar2(100) := get_env_var (p_var_name => 'https_host'); --- necessary if you have an Oracle 12.2 database or higher (see instructions) 8 | g_address1 constant varchar2(500) := get_env_var (p_var_name => 'address1'); ----- the CAN SPAM act requires that you specify the organization's address 9 | g_city constant varchar2(500) := get_env_var (p_var_name => 'city'); --------- the CAN SPAM act requires that you specify the organization's address 10 | g_state constant varchar2(500) := get_env_var (p_var_name => 'state'); -------- the CAN SPAM act requires that you specify the organization's address 11 | g_zip constant varchar2(500) := get_env_var (p_var_name => 'zip'); ---------- the CAN SPAM act requires that you specify the organization's address 12 | g_county constant varchar2(500) := get_env_var (p_var_name => 'country'); ------ the CAN SPAM act requires that you specify the organization's address 13 | g_company_name constant varchar2(100) := get_env_var (p_var_name => 'company'); ------ whatever your organization is called 14 | g_reply_to constant varchar2(100) := get_env_var (p_var_name => 'email'); -------- the email that you've authenticated with Mailchimp 15 | g_from_name constant varchar2(100) := get_env_var (p_var_name => 'from_name'); ---- the name your emails will appear to be from 16 | g_username constant varchar2(50) := 'admin'; ------------------------------------ arbitrary - can be anything 17 | 18 | -- see package specs 19 | function create_list (p_list_name in varchar2, 20 | p_permission_reminder in varchar2) 21 | return varchar2 22 | is 23 | l_scope logger_logs.scope%type := gc_scope_prefix || 'create_list'; 24 | l_params logger.tab_param; 25 | l_body varchar2(1000); 26 | l_response clob; 27 | l_confirmation varchar2(1000); 28 | l_list_id varchar2(50); 29 | begin 30 | logger.append_param(l_params, 'p_list_name', p_list_name); 31 | logger.append_param(l_params, 'p_permission_reminder', p_permission_reminder); 32 | logger.log('START', l_scope, null, l_params); 33 | 34 | l_body := '{"name":"'||p_list_name||'","contact":{"company":"'||g_company_name||'","address1":"'||g_address1||'","city":"'||g_city||'","state":"'||g_state||'","zip":"'||g_zip||'","country":"'||g_county||'","phone":""}'; 35 | l_body := l_body||',"permission_reminder":"'||p_permission_reminder||'","campaign_defaults":{"from_name":"'||g_from_name||'","from_email":"'||g_reply_to||'","subject":"","language":"en"},"email_type_option":true}'; 36 | 37 | logger.log('l_body :', l_scope, l_body); 38 | 39 | l_response := apex_web_service.make_rest_request( 40 | p_url => g_url_prefix||'/lists/' 41 | , p_http_method => 'POST' 42 | , p_username => g_username 43 | , p_password => g_password 44 | , p_body => l_body 45 | , p_wallet_path => g_wallet_path 46 | , p_https_host => g_https_host 47 | ); 48 | 49 | l_list_id := json_value(l_response, '$.id'); 50 | 51 | logger.log('list id :' , l_scope, l_list_id); 52 | logger.log('l_response : ', l_scope, l_response); 53 | 54 | logger.log('END', l_scope); 55 | return l_list_id; 56 | exception when others then 57 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 58 | raise; 59 | end create_list; 60 | 61 | -- see package specs 62 | procedure add_subscriber ( p_list_id in varchar2, 63 | p_email in varchar2, 64 | p_fname in varchar2, 65 | p_lname in varchar2, 66 | p_success out boolean) 67 | is 68 | l_scope logger_logs.scope%type := gc_scope_prefix || 'add_subscriber'; 69 | l_params logger.tab_param; 70 | l_body varchar2(1000); 71 | l_response clob; 72 | l_confirmation varchar2(1000); 73 | begin 74 | logger.append_param(l_params, 'p_list_id', p_list_id); 75 | logger.append_param(l_params, 'p_email', p_email); 76 | logger.append_param(l_params, 'p_fname', p_fname); 77 | logger.append_param(l_params, 'p_lname', p_lname); 78 | logger.log('START', l_scope, null, l_params); 79 | 80 | l_body := '{"email_address":"'||p_email||'","status":"subscribed","merge_fields":{"FNAME":"'||p_fname||'","LNAME":"'||p_lname||'"}}'; 81 | 82 | l_response := apex_web_service.make_rest_request( 83 | p_url => g_url_prefix||'/lists/'||p_list_id||'/members/' 84 | , p_http_method => 'POST' 85 | , p_username => g_username 86 | , p_password => g_password 87 | , p_body => l_body 88 | , p_wallet_path => g_wallet_path 89 | , p_https_host => g_https_host 90 | ); 91 | 92 | l_confirmation := json_value(l_response, '$.status'); 93 | 94 | 95 | if l_confirmation = 'subscribed' then 96 | p_success := true; 97 | logger.log('Success! :', l_scope, l_confirmation); 98 | else 99 | p_success := false; 100 | logger.log('Failure :', l_scope, l_response); 101 | end if; 102 | 103 | logger.log('END', l_scope); 104 | exception when others then 105 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 106 | raise; 107 | end add_subscriber; 108 | 109 | -- see package specs 110 | procedure remove_subscriber ( p_list_id in varchar2, 111 | p_email in varchar2, 112 | p_success out boolean) 113 | is 114 | l_scope logger_logs.scope%type := gc_scope_prefix || 'remove_subscriber'; 115 | l_params logger.tab_param; 116 | l_response clob; 117 | l_subscriber_hash varchar2(200); 118 | l_confirmation varchar2(1000); 119 | l_count number; 120 | begin 121 | logger.append_param(l_params, 'p_list_id', p_list_id); 122 | logger.append_param(l_params, 'p_email', p_email); 123 | logger.log('START', l_scope, null, l_params); 124 | 125 | select standard_hash(p_email, 'MD5') 126 | into l_subscriber_hash 127 | from dual; 128 | 129 | l_response := apex_web_service.make_rest_request( 130 | p_url => g_url_prefix||'/lists/'||p_list_id||'/members/'||l_subscriber_hash 131 | , p_http_method => 'DELETE' 132 | , p_username => g_username 133 | , p_password => g_password 134 | , p_wallet_path => g_wallet_path 135 | , p_https_host => g_https_host 136 | ); 137 | 138 | SELECT count(*) 139 | into l_count 140 | from table(mailchimp_pkg.get_list_of_subscribers ( p_list_id => p_list_id)) 141 | where email_address = p_email; 142 | 143 | if l_count = 0 then 144 | p_success := true; 145 | else 146 | p_success := false; 147 | end if; 148 | 149 | logger.log('END', l_scope); 150 | exception when others then 151 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 152 | raise; 153 | end remove_subscriber; 154 | 155 | -- see package specs 156 | function get_list_of_subscribers ( p_list_id in varchar2) -- the email list_id 157 | RETURN subscriber_typ_set PIPELINED 158 | is 159 | TYPE subscriber_table IS table of subscriber_typ_TBL%ROWTYPE INDEX BY PLS_INTEGER; 160 | l_scope logger_logs.scope%type := gc_scope_prefix || 'get_list_of_subscribers'; 161 | l_params logger.tab_param; 162 | l_subscriber_set subscriber_table; 163 | l_subscribers subscriber_typ_set := subscriber_typ_set(); 164 | l_response clob; 165 | l_total_items integer; 166 | l_counter integer; 167 | begin 168 | logger.append_param(l_params, 'p_list_id', p_list_id); 169 | logger.log('START', l_scope, null, l_params); 170 | 171 | l_response:= apex_web_service.make_rest_request( 172 | p_url => g_url_prefix||'/lists/'||p_list_id||'/members?offset=0&count=10000' 173 | , p_http_method => 'GET' 174 | , p_username => g_username 175 | , p_password => g_password 176 | , p_wallet_path => g_wallet_path 177 | , p_https_host => g_https_host 178 | ); 179 | 180 | l_total_items := json_value(l_response, '$.total_items'); 181 | logger.log('l_total_items :', l_scope, to_char(l_total_items)); 182 | 183 | for i in 1..l_total_items 184 | loop 185 | l_counter := i -1; 186 | l_subscriber_set(i).email_address := json_value(l_response, '$.members['||l_counter||'].email_address'); 187 | l_subscriber_set(i).first_name := json_value(l_response, '$.members['||l_counter||'].merge_fields.FNAME'); 188 | l_subscriber_set(i).last_name := json_value(l_response, '$.members['||l_counter||'].merge_fields.LNAME'); 189 | l_subscriber_set(i).status := json_value(l_response, '$.members['||l_counter||'].status'); 190 | 191 | end loop; 192 | 193 | for i in 1..l_total_items 194 | loop 195 | PIPE ROW (subscriber_typ(l_subscriber_set(i).email_address, 196 | l_subscriber_set(i).first_name, 197 | l_subscriber_set(i).last_name, 198 | l_subscriber_set(i).status 199 | ) 200 | ); 201 | end loop; 202 | 203 | logger.log('END', l_scope); 204 | exception when others then 205 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 206 | raise; 207 | end get_list_of_subscribers; 208 | 209 | --see package specs 210 | function get_list_of_merge_fields (p_list_id in varchar2) 211 | return merge_field_typ_set PIPELINED 212 | is 213 | TYPE merge_field_table IS table of merge_field_typ_tbl%ROWTYPE INDEX BY PLS_INTEGER; 214 | l_scope logger_logs.scope%type := gc_scope_prefix || 'get_list_of_merge_fields'; 215 | l_params logger.tab_param; 216 | l_merge_field_set merge_field_table; 217 | l_merge_fields merge_field_typ_set := merge_field_typ_set(); 218 | l_response clob; 219 | l_total_items integer; 220 | l_counter integer; 221 | begin 222 | logger.append_param(l_params, 'p_list_id', p_list_id); 223 | logger.log('START', l_scope, null, l_params); 224 | 225 | l_response:= apex_web_service.make_rest_request( 226 | p_url => g_url_prefix||'/lists/'||p_list_id||'/merge-fields/' 227 | , p_http_method => 'GET' 228 | , p_username => g_username 229 | , p_password => g_password 230 | , p_wallet_path => g_wallet_path 231 | , p_https_host => g_https_host 232 | ); 233 | 234 | l_total_items := json_value(l_response, '$.total_items'); 235 | logger.log('l_total_items :', l_scope, to_char(l_total_items)); 236 | 237 | for i in 1..l_total_items 238 | loop 239 | l_counter := i -1; 240 | l_merge_field_set(i).merge_id := json_value(l_response, '$.merge_fields['||l_counter||'].merge_id'); 241 | l_merge_field_set(i).tag := json_value(l_response, '$.merge_fields['||l_counter||'].tag'); 242 | l_merge_field_set(i).name := json_value(l_response, '$.merge_fields['||l_counter||'].name'); 243 | l_merge_field_set(i).default_value := json_value(l_response, '$.merge_fields['||l_counter||'].default_value'); 244 | end loop; 245 | 246 | for i in 1..l_total_items 247 | loop 248 | PIPE ROW (merge_field_typ(l_merge_field_set(i).merge_id, 249 | l_merge_field_set(i).tag, 250 | l_merge_field_set(i).name, 251 | l_merge_field_set(i).default_value 252 | ) 253 | ); 254 | end loop; 255 | logger.log('END', l_scope); 256 | exception when others then 257 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 258 | raise; 259 | end get_list_of_merge_fields; 260 | 261 | -- see package specs 262 | procedure create_merge_field(p_list_id in varchar2, 263 | p_merge_field_tag in varchar2, 264 | p_merge_field_name in varchar2, 265 | p_merge_id out integer, 266 | p_tag out varchar2) 267 | is 268 | l_scope logger_logs.scope%type := gc_scope_prefix || 'create_merge_field'; 269 | l_params logger.tab_param; 270 | l_body varchar2(1000); 271 | l_response varchar2(2000); 272 | l_tag_count number; 273 | procedure check_if_already_there is 274 | begin 275 | SELECT merge_id, tag 276 | INTO p_merge_id, p_tag 277 | FROM TABLE(mailchimp_pkg.get_list_of_merge_fields(p_list_id => p_list_id)) 278 | where tag = p_merge_field_tag; 279 | logger.log('The tag already exists in this list.', l_scope, null, l_params); 280 | logger.log('p_merge_id :', l_scope, to_char(p_merge_id)); 281 | logger.log('p_tag :' , l_scope, p_tag); 282 | exception when no_data_found then 283 | logger.log('The tag does not exist yet in this list', l_scope, null, l_params); 284 | end check_if_already_there; 285 | begin 286 | logger.append_param(l_params, 'p_list_id', p_list_id); 287 | logger.append_param(l_params, 'p_merge_field_tag', p_merge_field_tag); 288 | logger.append_param(l_params, 'p_merge_field_name', p_merge_field_name); 289 | logger.log('START', l_scope, null, l_params); 290 | 291 | if length(p_merge_field_tag) > 10 then 292 | logger.log_error('p_merge_field_tag cannot be more than 10 characters.', l_scope, null, l_params); 293 | raise_application_error(-20456, 'Merge field too long'); 294 | end if; 295 | 296 | check_if_already_there; 297 | if p_merge_id is not null then return; end if; 298 | 299 | l_body := '{"tag":"'||p_merge_field_tag||'", "name":"'||p_merge_field_name||'", "type":"text"}'; 300 | 301 | l_response := apex_web_service.make_rest_request( 302 | p_url => g_url_prefix||'lists/'||p_list_id||'/merge-fields/' 303 | , p_http_method => 'POST' 304 | , p_username => g_username 305 | , p_password => g_password 306 | , p_body => l_body 307 | , p_wallet_path => g_wallet_path 308 | , p_https_host => g_https_host 309 | ); 310 | 311 | p_merge_id := json_value(l_response, '$.merge_id'); 312 | p_tag := json_value(l_response, '$.tag'); 313 | 314 | if p_merge_id is null then 315 | logger.log_error('Unhandled Error :', l_scope, l_response); 316 | else 317 | logger.log('p_merge_id :', l_scope, to_char(p_merge_id)); 318 | logger.log('p_tag :' , l_scope, p_tag); 319 | end if; 320 | 321 | logger.log('END', l_scope); 322 | exception when others then 323 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 324 | raise; 325 | end create_merge_field; 326 | 327 | -- see package specs 328 | procedure update_merge_field (p_list_id in varchar2, 329 | p_merge_field_tag in varchar2, 330 | p_merge_value in varchar2, 331 | p_success out boolean) 332 | is 333 | l_scope logger_logs.scope%type := gc_scope_prefix || 'update_merge_field'; 334 | l_params logger.tab_param; 335 | l_merge_id integer; 336 | l_body varchar2(1000); 337 | l_response clob; 338 | l_confirmation varchar2(1000); 339 | begin 340 | logger.append_param(l_params, 'p_list_id', p_list_id); 341 | logger.append_param(l_params, 'p_merge_field_tag', p_merge_field_tag); 342 | logger.append_param(l_params, 'p_merge_value', p_merge_value); 343 | logger.log('START', l_scope, null, l_params); 344 | 345 | begin 346 | select merge_id 347 | into l_merge_id 348 | from table(mailchimp_pkg.get_list_of_merge_fields(p_list_id => p_list_id)) 349 | where tag = p_merge_field_tag; 350 | exception when no_data_found then 351 | logger.log_error('Tag does not exist in this list. It must be created 1st.', l_scope, null, l_params); 352 | raise; 353 | end; 354 | 355 | l_body := '{"name":"'||p_merge_field_tag||'", "type":"text", "default_value": "'||p_merge_value||'", "options": {"size": 2000}}'; 356 | 357 | l_response := apex_web_service.make_rest_request( 358 | p_url => g_url_prefix||'/lists/'||p_list_id||'/merge-fields/'||l_merge_id 359 | , p_http_method => 'PATCH' 360 | , p_username => g_username 361 | , p_password => g_password 362 | , p_body => l_body 363 | , p_wallet_path => g_wallet_path 364 | , p_https_host => g_https_host 365 | ); 366 | 367 | l_confirmation := json_value(l_response, '$.default_value'); 368 | 369 | 370 | if l_confirmation = p_merge_value then 371 | p_success := true; 372 | logger.log('Successfully updated merge field to :', l_scope, l_confirmation); 373 | else 374 | p_success := false; 375 | logger.log('Failure :', l_scope, l_confirmation); 376 | end if; 377 | 378 | 379 | logger.log('END', l_scope); 380 | exception when others then 381 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 382 | raise; 383 | end update_merge_field; 384 | 385 | -- see package specs 386 | procedure create_template ( p_template_name in varchar2, 387 | p_html in clob, 388 | p_template_id out integer) 389 | is 390 | l_scope logger_logs.scope%type := gc_scope_prefix || 'create_template'; 391 | l_params logger.tab_param; 392 | l_body varchar2(1000); 393 | l_response clob; 394 | begin 395 | logger.append_param(l_params, 'p_template_name', p_template_name); 396 | logger.log('START', l_scope, null, l_params); 397 | 398 | l_body := '{"name":"'||p_template_name||'","html":"'||p_html||'"}'; 399 | l_response := apex_web_service.make_rest_request( 400 | p_url => g_url_prefix||'/templates' 401 | , p_http_method => 'POST' 402 | , p_username => g_username 403 | , p_password => g_password 404 | , p_body => l_body 405 | , p_wallet_path => g_wallet_path 406 | , p_https_host => g_https_host 407 | ); 408 | 409 | p_template_id := json_value(l_response, '$.id'); 410 | logger.log('p_template_id :', l_scope, to_char(p_template_id)); 411 | 412 | logger.log('END', l_scope); 413 | exception when others then 414 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 415 | raise; 416 | end create_template; 417 | 418 | -- see package specs 419 | procedure update_template ( p_template_id in integer, 420 | p_html in clob, 421 | p_success out boolean) 422 | is 423 | l_scope logger_logs.scope%type := gc_scope_prefix || 'update_template'; 424 | l_params logger.tab_param; 425 | l_body clob; 426 | l_response clob; 427 | l_template_id integer; 428 | begin 429 | logger.append_param(l_params, 'p_template_id', p_template_id); 430 | logger.log('START', l_scope, null, l_params); 431 | 432 | l_body := '{"html":"'||p_html||'"}'; 433 | 434 | l_response := apex_web_service.make_rest_request( 435 | p_url => g_url_prefix||'/templates/'||p_template_id 436 | , p_http_method => 'PATCH' 437 | , p_username => g_username 438 | , p_password => g_password 439 | , p_body => l_body 440 | , p_wallet_path => g_wallet_path 441 | , p_https_host => g_https_host 442 | ); 443 | 444 | l_template_id := json_value(l_response, '$.id'); 445 | 446 | if l_template_id = p_template_id then 447 | p_success := true; 448 | else 449 | p_success := false; 450 | end if; 451 | 452 | logger.log('END', l_scope); 453 | exception when others then 454 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 455 | raise; 456 | end update_template; 457 | 458 | -- see package specs 459 | procedure create_campaign ( p_list_id in varchar2, 460 | p_subject_line in varchar2, 461 | p_title in varchar2, 462 | p_template_id in number, 463 | p_campaign_id out varchar2, 464 | p_send_url out varchar2) 465 | is 466 | l_scope logger_logs.scope%type := gc_scope_prefix || 'create_campaign'; 467 | l_params logger.tab_param; 468 | l_body varchar2(1000); 469 | l_response clob; 470 | l_campaign_id varchar2(100); 471 | begin 472 | logger.append_param(l_params, 'p_list_id', p_list_id); 473 | logger.append_param(l_params, 'p_subject_line', p_subject_line); 474 | logger.append_param(l_params, 'p_title', p_title); 475 | logger.append_param(l_params, 'p_template_id', p_template_id); 476 | logger.append_param(l_params, 'g_reply_to', g_reply_to); 477 | logger.append_param(l_params, 'g_from_name', g_from_name); 478 | logger.append_param(l_params, 'p_send_url', p_send_url); 479 | logger.log('START', l_scope, null, l_params); 480 | l_body := '{"recipients":{"list_id":"'||p_list_id||'"},"type":"regular","settings":{"subject_line":"'||p_subject_line||'", "title": "'||p_title||'","template_id": '||p_template_id||',"reply_to":"'||g_reply_to||'","from_name":"'||g_from_name||'"}}'; 481 | 482 | l_response := apex_web_service.make_rest_request( 483 | p_url => g_url_prefix||'/campaigns' 484 | , p_http_method => 'POST' 485 | , p_username => g_username 486 | , p_password => g_password 487 | , p_body => l_body 488 | , p_wallet_path => g_wallet_path 489 | , p_https_host => g_https_host 490 | ); 491 | 492 | l_campaign_id := json_value(l_response, '$.id'); 493 | logger.log('l_campaign_id :', l_scope, l_campaign_id); 494 | p_campaign_id := l_campaign_id; 495 | p_send_url := json_value(l_response, '$."_links"[3].href'); 496 | logger.log('p_send_url :', l_scope, p_send_url); 497 | 498 | logger.log('END', l_scope); 499 | exception when others then 500 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 501 | raise; 502 | end create_campaign; 503 | 504 | --see package specs 505 | procedure send_campaign_checklist (p_campaign_id in varchar2, --- the unique id of the campaign 506 | p_ready out boolean) 507 | is 508 | l_scope logger_logs.scope%type := gc_scope_prefix || 'send_campaign_checklist'; 509 | l_params logger.tab_param; 510 | l_response clob; 511 | l_ready varchar2(10); 512 | begin 513 | logger.append_param(l_params, 'p_campaign_id', p_campaign_id); 514 | logger.log('START', l_scope, null, l_params); 515 | 516 | l_response:= apex_web_service.make_rest_request( 517 | p_url => g_url_prefix||'/campaigns/'||p_campaign_id||'/send-checklist' 518 | , p_http_method => 'GET' 519 | , p_username => g_username 520 | , p_password => g_password 521 | , p_wallet_path => g_wallet_path 522 | , p_https_host => g_https_host 523 | ); 524 | l_ready := json_value(l_response, '$.is_ready'); 525 | if l_ready = 'true' then 526 | logger.log('The campaign is ready to send.', l_scope, null, l_params); 527 | p_ready := true; 528 | else 529 | logger.log('The campaign is not ready to send.', l_scope, l_response); 530 | p_ready := false; 531 | end if; 532 | 533 | logger.log('END', l_scope); 534 | exception when others then 535 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 536 | raise; 537 | end send_campaign_checklist; 538 | 539 | -- see package specs 540 | procedure send_campaign (p_send_url in varchar2, 541 | p_success out boolean) 542 | is 543 | l_scope logger_logs.scope%type := gc_scope_prefix || 'send_campaign'; 544 | l_params logger.tab_param; 545 | l_response clob; 546 | begin 547 | logger.append_param(l_params, 'p_send_url', p_send_url); 548 | logger.log('START', l_scope, null, l_params); 549 | 550 | l_response := apex_web_service.make_rest_request( 551 | p_url => p_send_url 552 | , p_http_method => 'POST' 553 | , p_username => g_username 554 | , p_password => g_password 555 | , p_wallet_path => g_wallet_path 556 | , p_https_host => g_https_host 557 | ); 558 | 559 | if length(l_response) = 0 or l_response is null then 560 | p_success := true; 561 | logger.log('Success!', l_scope, null, l_params); 562 | else 563 | p_success := false; 564 | logger.log('l_response :', l_scope, l_response); 565 | end if; 566 | 567 | logger.log('END', l_scope); 568 | exception when others then 569 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 570 | raise; 571 | end send_campaign; 572 | 573 | function get_campaign_history return campaign_history_typ_set PIPELINED 574 | is 575 | TYPE campaign_table IS table of campaign_history_typ_tbl%ROWTYPE INDEX BY PLS_INTEGER; 576 | l_scope logger_logs.scope%type := gc_scope_prefix || 'get_campaign_history'; 577 | l_params logger.tab_param; 578 | l_campaign_set campaign_table; 579 | l_campaigns campaign_history_typ_set := campaign_history_typ_set(); 580 | l_response clob; 581 | l_total_items integer; 582 | l_counter integer; 583 | l_send_time varchar2(100); 584 | begin 585 | logger.log('START', l_scope, null, l_params); 586 | 587 | l_response:= apex_web_service.make_rest_request( 588 | p_url => g_url_prefix||'/campaigns/' 589 | , p_http_method => 'GET' 590 | , p_username => g_username 591 | , p_password => g_password 592 | , p_wallet_path => g_wallet_path 593 | , p_https_host => g_https_host 594 | ); 595 | 596 | l_total_items := json_value(l_response, '$.total_items'); 597 | logger.log('l_total_items :', l_scope, to_char(l_total_items)); 598 | 599 | for i in 1..l_total_items 600 | loop 601 | l_counter := i -1; 602 | l_campaign_set(i).campaign_id := json_value(l_response, '$.campaigns['||l_counter||'].id'); 603 | l_campaign_set(i).emails_sent := json_value(l_response, '$.campaigns['||l_counter||'].emails_sent'); 604 | l_send_time := json_value(l_response, '$.campaigns['||l_counter||'].send_time'); 605 | l_campaign_set(i).send_time := to_date(substr(l_send_time,1,instr(l_send_time,'+')-1), 'YYYY-MM-DD"T"HH24:MI:SS'); 606 | l_campaign_set(i).recipient_list_id := json_value(l_response, '$.campaigns['||l_counter||'].recipients.list_id'); 607 | l_campaign_set(i).template_id := json_value(l_response, '$.campaigns['||l_counter||'].settings.template_id'); 608 | l_campaign_set(i).subject_line := json_value(l_response, '$.campaigns['||l_counter||'].settings.subject_line'); 609 | l_campaign_set(i).from_name := json_value(l_response, '$.campaigns['||l_counter||'].settings.from_name'); 610 | l_campaign_set(i).opens := json_value(l_response, '$.campaigns['||l_counter||'].report_summary.opens'); 611 | l_campaign_set(i).unique_opens := json_value(l_response, '$.campaigns['||l_counter||'].report_summary.unique_opens'); 612 | l_campaign_set(i).open_rate := json_value(l_response, '$.campaigns['||l_counter||'].report_summary.open_rate'); 613 | l_campaign_set(i).clicks := json_value(l_response, '$.campaigns['||l_counter||'].report_summary.clicks'); 614 | l_campaign_set(i).cancel_send := json_value(l_response, '$.campaigns['||l_counter||']."_links"[4].href'); 615 | end loop; 616 | 617 | for i in 1..l_total_items 618 | loop 619 | PIPE ROW (campaign_history_typ(l_campaign_set(i).campaign_id, 620 | l_campaign_set(i).emails_sent, 621 | l_campaign_set(i).send_time, 622 | l_campaign_set(i).recipient_list_id, 623 | l_campaign_set(i).template_id, 624 | l_campaign_set(i).subject_line, 625 | l_campaign_set(i).from_name, 626 | l_campaign_set(i).opens, 627 | l_campaign_set(i).unique_opens, 628 | l_campaign_set(i).open_rate, 629 | l_campaign_set(i).clicks, 630 | l_campaign_set(i).cancel_send 631 | ) 632 | ); 633 | end loop; 634 | 635 | logger.log('END', l_scope); 636 | exception when others then 637 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 638 | raise; 639 | end get_campaign_history; 640 | 641 | -- see package specs 642 | function get_env_var (p_var_name in varchar2) return varchar2 643 | is 644 | l_scope logger_logs.scope%type := gc_scope_prefix || 'get_env_var'; 645 | l_params logger.tab_param; 646 | l_var_val varchar2(200); 647 | begin 648 | logger.append_param(l_params, 'p_var_name', p_var_name); 649 | logger.log('START', l_scope, null, l_params); 650 | 651 | select variable_value 652 | into l_var_val 653 | from mailchimp_env_var 654 | where upper(variable_name) = upper(p_var_name); 655 | 656 | logger.log('END', l_scope); 657 | return l_var_val; 658 | exception 659 | when no_data_found then 660 | logger.log_info('Variable name not recognized.', l_scope, null, l_params); 661 | return null; 662 | when others then 663 | logger.log_error('Unhandled Exception', l_scope, null, l_params); 664 | raise; 665 | end get_env_var; 666 | 667 | end mailchimp_pkg; 668 | / -------------------------------------------------------------------------------- /source/packages/mailchimp_pkg.pks: -------------------------------------------------------------------------------- 1 | create or replace package mailchimp_pkg as 2 | 3 | --create a new mailing list 4 | function create_list (p_list_name in varchar2, --- the name you want to give your new mailing list 5 | p_permission_reminder in varchar2) --- a sentence to remind your recipients how they got on this mailing list 6 | return varchar2; --------------------- the resulting id of the newly created list & a confirmation that the operation was successful 7 | 8 | -- add a subscriber to a subscriber list 9 | procedure add_subscriber ( p_list_id in varchar2, --- the id of the list you are adding a subscriber to 10 | p_email in varchar2, --- the email of the new subscriber 11 | p_fname in varchar2, --- the 1st name of this subscriber 12 | p_lname in varchar2, --- the last name of this subscriber 13 | p_success out boolean); -- a confirmation of that adding the subscriber was successful 14 | 15 | -- delete subscriber from list 16 | procedure remove_subscriber ( p_list_id in varchar2, --- the id of the list you are adding a subscriber to 17 | p_email in varchar2, --- the email of the subscriber you want to remove 18 | p_success out boolean); -- a confirmation of that removing the subscriber was successful 19 | 20 | --print list of subscribers 21 | function get_list_of_subscribers ( p_list_id in varchar2) -- the email list_id 22 | return subscriber_typ_set PIPELINED; 23 | 24 | --print list of merge fields for a given email list 25 | function get_list_of_merge_fields (p_list_id in varchar2) -- the email list_id 26 | return merge_field_typ_set PIPELINED; 27 | 28 | --create a new merge_field 29 | procedure create_merge_field(p_list_id in varchar2, --- the id of the list that would make use of this merge id 30 | p_merge_field_tag in varchar2, --- the name you want to give the merge variable (10 char max) 31 | p_merge_field_name in varchar2, --- a more descriptive name 32 | p_merge_id out integer, 33 | p_tag out varchar2); 34 | 35 | --update the default value of an existing merge_field 36 | procedure update_merge_field (p_list_id in varchar2, --- the id of the list 37 | p_merge_field_tag in varchar2, --- the tag of the merge field 38 | p_merge_value in varchar2, --- the value you want to pass into the email 39 | p_success out boolean); 40 | 41 | --create a new template 42 | procedure create_template ( p_template_name in varchar2, --- the name you want to give the template 43 | p_html in clob, ------- the html of the email template 44 | p_template_id out integer); --- the id of the newly created template 45 | 46 | -- update an existing template 47 | procedure update_template ( p_template_id in integer, ----- the id of the pre-existing Mailchimp template that you wish to edit 48 | p_html in clob, -------- the html that you wish to pass into the above specified template 49 | p_success out boolean); --- a confirmation of whether the operation was successful 50 | --create a new email campaign 51 | procedure create_campaign ( p_list_id in varchar2, ----- the list_id that should receive your email 52 | p_subject_line in varchar2, ----- the subject line of your email 53 | p_title in varchar2, ----- a title for your administrative purposes 54 | p_template_id in number, ------- the template the email should use 55 | p_campaign_id out varchar2, ---- then unique id of the newly created campaign 56 | p_send_url out varchar2); --- the URL of the as-yet unsent email 57 | 58 | --see if campaign is ready to be sent 59 | procedure send_campaign_checklist (p_campaign_id in varchar2, --- the unique id of the campaign 60 | p_ready out boolean); -- a confirmation of whether or not it is ready to be sent 61 | 62 | 63 | --send email campaign 64 | procedure send_campaign (p_send_url in varchar2, ---- the URL of the email you wish to send (see above) 65 | p_success out boolean); --- a confirmation of whether this operation was successful 66 | 67 | 68 | -- get history of all campaigns 69 | function get_campaign_history return campaign_history_typ_set PIPELINED; 70 | 71 | --retrieve environment variables written to the database 72 | function get_env_var (p_var_name in varchar2) return varchar2; 73 | 74 | end mailchimp_pkg; 75 | / -------------------------------------------------------------------------------- /source/tables/campaign_history_typ_tbl.sql: -------------------------------------------------------------------------------- 1 | -- NOTE : The intended use of this table is not that you populate it. It merely supports the 2 | -- PIPELINED table output of the get_campaign_history procedure 3 | create table campaign_history_typ_tbl ( 4 | campaign_id VARCHAR2(50), 5 | emails_sent INTEGER, 6 | send_time DATE, 7 | recipient_list_id VARCHAR2(2000), 8 | template_id INTEGER, 9 | subject_line VARCHAR2(100), 10 | from_name VARCHAR2(200), 11 | opens INTEGER, 12 | unique_opens INTEGER, 13 | open_rate INTEGER, 14 | clicks INTEGER, 15 | cancel_send VARCHAR2(1000) 16 | ) 17 | / -------------------------------------------------------------------------------- /source/tables/mailchimp_env_var.sql: -------------------------------------------------------------------------------- 1 | create table mailchimp_env_var ( 2 | id NUMBER GENERATED BY DEFAULT ON NULL AS IDENTITY, 3 | variable_name VARCHAR2(100), 4 | variable_value VARCHAR2(100) 5 | ); -------------------------------------------------------------------------------- /source/tables/merge_field_typ_tbl.sql: -------------------------------------------------------------------------------- 1 | -- NOTE : The intended use of this table is not that you populate it. It merely supports the 2 | -- PIPELINED table output of the get_list_of_merge_fields procedure 3 | create table merge_field_typ_tbl ( 4 | merge_id INTEGER, 5 | tag VARCHAR2(50), 6 | name VARCHAR2(50), 7 | default_value VARCHAR2(2000) 8 | ) 9 | / -------------------------------------------------------------------------------- /source/tables/subscriber_typ_tbl.sql: -------------------------------------------------------------------------------- 1 | -- NOTE : The intended use of this table is not that you populate it. It merely supports the 2 | -- PIPELINED table output of the get_list_of_subscribers procedure 3 | CREATE TABLE subscriber_typ_tbl ( 4 | email_address VARCHAR2(100), 5 | first_name VARCHAR2(50), 6 | last_name VARCHAR2(50), 7 | status varchar2(50)) 8 | / -------------------------------------------------------------------------------- /source/types/campaign_history_typ.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE campaign_history_typ AS OBJECT ( 2 | campaign_id VARCHAR2(50), 3 | emails_sent INTEGER, 4 | send_time DATE, 5 | recipient_list_id VARCHAR2(2000), 6 | template_id INTEGER, 7 | subject_line VARCHAR2(100), 8 | from_name VARCHAR2(200), 9 | opens INTEGER, 10 | unique_opens INTEGER, 11 | open_rate INTEGER, 12 | clicks INTEGER, 13 | cancel_send VARCHAR2(1000) 14 | ) 15 | / -------------------------------------------------------------------------------- /source/types/campaign_history_typ_set.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE campaign_history_typ_set AS TABLE OF campaign_history_typ 2 | / -------------------------------------------------------------------------------- /source/types/merge_field_typ.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE merge_field_typ AS OBJECT ( 2 | merge_id INTEGER, 3 | tag VARCHAR2(50), 4 | name VARCHAR2(50), 5 | default_value VARCHAR2(2000) 6 | ) 7 | / -------------------------------------------------------------------------------- /source/types/merge_field_typ_set.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE merge_field_typ_set AS TABLE OF merge_field_typ 2 | / -------------------------------------------------------------------------------- /source/types/subscriber_typ.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE subscriber_typ AS OBJECT ( 2 | email_address VARCHAR2(100), 3 | first_name VARCHAR2(50), 4 | last_name VARCHAR2(50), 5 | status varchar2(50) 6 | ) 7 | / -------------------------------------------------------------------------------- /source/types/subscriber_typ_set.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE subscriber_typ_set AS TABLE OF subscriber_typ 2 | / -------------------------------------------------------------------------------- /source/uninstall.sql: -------------------------------------------------------------------------------- 1 | drop table subscriber_typ_tbl; 2 | drop type subscriber_typ_set; 3 | drop type subscriber_typ; 4 | drop table merge_field_typ_tbl; 5 | drop type merge_field_typ_set; 6 | drop type merge_field_typ; 7 | drop table campaign_history_typ_tbl; 8 | drop type campaign_history_typ_set; 9 | drop type campaign_history_typ; 10 | drop table mailchimp_env_var; 11 | drop package mailchimp_pkg; 12 | / --------------------------------------------------------------------------------