├── 01_setup_private_keys.sql
├── 02A_send_email_mailgun.sql
├── 02B_send_email_sendgrid.sql
├── 02C_send_email_sendinblue.sql
├── 02D_send_email_mailjet.sql
├── 02E_send_email_mailersend.sql
├── 02_send_email_message.sql
├── 03_setup_messages_table.sql
├── 04A_setup_mailgun_web_hooks.sql
├── 04B_setup_sendgrid_web_hooks.sql
├── 04C_setup_sendinblue_web_hooks.sql
├── 04D_setup_mailjet_web_hooks.sql
├── 04E_setup_mailersend_web_hooks.sql
├── 05_create_email_message.sql
├── 99_(future)_setup_templates.sql
├── Mail_Providers
├── Mailersend.md
├── Mailgun.md
├── Mailjet.md
├── Sendgrid.md
└── Sendinblue.md
└── README.md
/01_setup_private_keys.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA IF NOT EXISTS private;
2 | CREATE TABLE IF NOT EXISTS private.keys (
3 | key text primary key not null,
4 | value text
5 | );
6 | REVOKE ALL ON TABLE private.keys FROM PUBLIC;
7 |
8 | /*******************************************************
9 | * IMPORTANT: INSERT YOUR KEYS IN THE COMMANDS BELOW *
10 | ********************************************************
11 |
12 | -- [SENDGRID_API_KEY]
13 |
14 | -- [PERSONAL_MAILGUN_DOMAIN]
15 |
16 | -- [PERSONAL_MAILGUN_API_KEY]
17 | -- (looks like this): api:key-xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx
18 |
19 | -- [SUPABASE_API_URL_HERE]
20 | -- Supabase Dashboard / settings / api / config / url
21 |
22 | -- [SUPABASE_PUBLIC_KEY_HERE]
23 | -- Supabase Dashboard / settings / api / anon-public key
24 | **************************************************************/
25 |
26 | INSERT INTO private.keys (key, value) values ('SENDGRID_API_KEY', '[SENDGRID_API_KEY]');
27 |
28 | INSERT INTO private.keys (key, value) values ('SENDINBLUE_API_KEY', '[SENDINBLUE_API_KEY]');
29 |
30 | INSERT INTO private.keys (key, value) values ('MAILERSEND_API_TOKEN', '[MAILERSEND_API_TOKEN]');
31 |
32 |
33 | INSERT INTO private.keys (key, value) values ('MAILJET_API_KEY', '[MAILJET_API_KEY]');
34 | INSERT INTO private.keys (key, value) values ('MAILJET_SECRET_KEY', '[MAILJET_SECRET_KEY]');
35 |
36 | INSERT INTO private.keys (key, value) values ('MAILGUN_DOMAIN', '[PERSONAL_MAILGUN_DOMAIN]');
37 | INSERT INTO private.keys (key, value) values ('MAILGUN_API_KEY', '[PERSONAL_MAILGUN_API_KEY]');
38 | INSERT INTO private.keys (key, value) values ('MAILGUN_WEBHOOK_URL',
39 | 'https://[SUPABASE_API_URL_HERE]/rest/v1/rpc/mailgun_webhook?apikey=[SUPABASE_PUBLIC_KEY_HERE]');
40 |
--------------------------------------------------------------------------------
/02A_send_email_mailgun.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE FUNCTION public.send_email_mailgun (message JSONB)
2 | RETURNS json
3 | LANGUAGE plpgsql
4 | SECURITY DEFINER -- required in order to read keys in the private schema
5 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
6 | -- SET search_path = admin, pg_temp;
7 | AS $$
8 | DECLARE
9 | retval json;
10 | MAILGUN_DOMAIN text;
11 | MAILGUN_API_KEY text;
12 | BEGIN
13 |
14 | SELECT value::text INTO MAILGUN_DOMAIN FROM private.keys WHERE key = 'MAILGUN_DOMAIN';
15 | IF NOT found THEN RAISE 'missing entry in private.keys: MAILGUN_DOMAIN'; END IF;
16 | SELECT value::text INTO MAILGUN_API_KEY FROM private.keys WHERE key = 'MAILGUN_API_KEY';
17 | IF NOT found THEN RAISE 'missing entry in private.keys: MAILGUN_API_KEY'; END IF;
18 |
19 | SELECT
20 | content INTO retval
21 | FROM
22 | http (('POST',
23 | 'https://api.mailgun.net/v3/' || MAILGUN_DOMAIN || '/messages',
24 | ARRAY[http_header ('Authorization',
25 | 'Basic ' || encode(MAILGUN_API_KEY::bytea, 'base64'::text))],
26 | 'application/x-www-form-urlencoded',
27 | 'from=' || urlencode (message->>'sender') ||
28 | '&to=' || urlencode (message->>'recipient') ||
29 | CASE WHEN message->>'cc' IS NOT NULL THEN '&cc=' || urlencode(message->>'cc') ELSE '' END ||
30 | CASE WHEN message->>'bcc' IS NOT NULL THEN '&bcc=' || urlencode(message->>'bcc') ELSE '' END ||
31 | CASE WHEN message->>'messageid' IS NOT NULL THEN '&v:messageid=' || urlencode(message->>'messageid') ELSE '' END ||
32 | '&subject=' || urlencode(message->>'subject') ||
33 | '&text=' || urlencode(message->>'text_body') ||
34 | '&html=' || urlencode(message->>'html_body')));
35 | -- if the message table exists,
36 | -- and the response from the mail server contains an id
37 | -- and the message from the mail server starts wtih 'Queued'
38 | -- mark this message as 'queued' in our message table, otherwise leave it as 'ready'
39 | IF (SELECT to_regclass('public.messages')) IS NOT NULL AND
40 | retval->'id' IS NOT NULL
41 | AND substring(retval->>'message',1,6) = 'Queued' THEN
42 | UPDATE public.messages SET status = 'queued' WHERE id = (message->>'messageid')::UUID;
43 | END IF;
44 |
45 | RETURN retval;
46 | END;
47 | $$;
48 | -- Do not allow this function to be called by public users (or called at all from the client)
49 | REVOKE EXECUTE on function public.send_email_mailgun FROM PUBLIC;
50 |
--------------------------------------------------------------------------------
/02B_send_email_sendgrid.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE FUNCTION public.send_email_sendgrid (message JSONB)
2 | RETURNS json
3 | LANGUAGE plpgsql
4 | SECURITY DEFINER -- required in order to read keys in the private schema
5 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
6 | -- SET search_path = admin, pg_temp;
7 | AS $$
8 | DECLARE
9 | retval json;
10 | SENDGRID_API_KEY text;
11 | BEGIN
12 | SELECT value::text INTO SENDGRID_API_KEY FROM private.keys WHERE key = 'SENDGRID_API_KEY';
13 | IF NOT found THEN RAISE 'missing entry in private.keys: SENDGRID_API_KEY'; END IF;
14 |
15 | SELECT
16 | * INTO retval
17 | FROM
18 | http (('POST',
19 | 'https://api.sendgrid.com/v3/mail/send',
20 | ARRAY[http_header ('Authorization',
21 | 'Bearer ' || SENDGRID_API_KEY)],
22 | 'application/json',
23 | json_build_object(
24 | 'personalizations',
25 | json_build_array(
26 | json_build_object(
27 | 'to', json_build_array(
28 | json_build_object('email', message->>'recipient')
29 | ))),
30 | 'from', json_build_object('email', message->>'sender'),
31 | 'subject', message->>'subject',
32 | 'content', json_build_array(
33 | json_build_object('type', 'text/plain', 'value', message->>'text_body'),
34 | json_build_object('type', 'text/html', 'value', message->>'html_body')
35 | ),
36 | 'custom_args', json_build_object(
37 | 'messageid', COALESCE(message->>'messageid',''))
38 | )::text));
39 |
40 | -- if the message table exists,
41 | -- and the response from the mail server contains an id
42 | -- and the message from the mail server starts wtih 'Queued'
43 | -- mark this message as 'queued' in our message table, otherwise leave it as 'ready'
44 |
45 | IF (SELECT to_regclass('public.messages')) IS NOT NULL AND
46 | retval::text = '202' THEN
47 | UPDATE public.messages SET status = 'queued' WHERE id = (message->>'messageid')::UUID;
48 | ELSE
49 | RAISE 'error sending message with sendgrid: %',retval;
50 | END IF;
51 |
52 | RETURN retval;
53 | END;
54 | $$;
55 | -- Do not allow this function to be called by public users (or called at all from the client)
56 | REVOKE EXECUTE on function public.send_email_sendgrid FROM PUBLIC;
57 |
--------------------------------------------------------------------------------
/02C_send_email_sendinblue.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE FUNCTION public.send_email_sendinblue (message JSONB)
2 | RETURNS json
3 | LANGUAGE plpgsql
4 | SECURITY DEFINER -- required in order to read keys in the private schema
5 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
6 | -- SET search_path = admin, pg_temp;
7 | AS $$
8 | DECLARE
9 | retval json;
10 | SENDINBLUE_API_KEY text;
11 | BEGIN
12 | SELECT value::text INTO SENDINBLUE_API_KEY FROM private.keys WHERE key = 'SENDINBLUE_API_KEY';
13 | IF NOT found THEN RAISE 'missing entry in private.keys: SENDINBLUE_API_KEY'; END IF;
14 |
15 | /*
16 | curl --request POST \
17 | --url https://api.sendinblue.com/v3/smtp/email \
18 | --header 'accept: application/json' \
19 | --header 'api-key:YOUR_API_KEY' \
20 | --header 'content-type: application/json' \
21 | --data '{
22 | "sender":{
23 | "name":"Sender Alex",
24 | "email":"senderalex@example.com"
25 | },
26 | "to":[
27 | {
28 | "email":"testmail@example.com",
29 | "name":"John Doe"
30 | }
31 | ],
32 | "subject":"Hello world",
33 | "htmlContent":"
Hello,
This is my first transactional email sent from Sendinblue."
34 | }'
35 | */
36 | SELECT
37 | * INTO retval
38 | FROM
39 | http
40 | ((
41 | 'POST',
42 | 'https://api.sendinblue.com/v3/smtp/email',
43 | ARRAY[http_header ('api-key', SENDINBLUE_API_KEY)],
44 | 'application/json',
45 | json_build_object(
46 | 'sender', json_build_object('name', message->>'sender', 'email', message->>'sender'),
47 | 'to',
48 | json_build_array(
49 | json_build_object('name', message->>'receipient', 'email', message->>'recipient')
50 | ),
51 | 'subject', message->>'subject',
52 | 'htmlContent', message->>'html_body',
53 | 'textConent', message->>'text_body',
54 | 'tags', json_build_array(
55 | message->>'messageid'
56 | )
57 | )::text
58 |
59 | ));
60 |
61 | -- if the message table exists,
62 | -- and the response from the mail server contains an id
63 | -- and the message from the mail server starts wtih 'Queued'
64 | -- mark this message as 'queued' in our message table, otherwise leave it as 'ready'
65 |
66 | IF (SELECT to_regclass('public.messages')) IS NOT NULL AND
67 | retval::text = '201' THEN
68 | UPDATE public.messages SET status = 'queued' WHERE id = (message->>'messageid')::UUID;
69 | ELSE
70 | RAISE 'error sending message with sendinblue: %',retval;
71 | END IF;
72 |
73 | RETURN retval;
74 | END;
75 | $$;
76 | -- Do not allow this function to be called by public users (or called at all from the client)
77 | REVOKE EXECUTE on function public.send_email_sendinblue FROM PUBLIC;
78 |
--------------------------------------------------------------------------------
/02D_send_email_mailjet.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE FUNCTION public.send_email_mailjet (message JSONB)
2 | RETURNS json
3 | LANGUAGE plpgsql
4 | SECURITY DEFINER -- required in order to read keys in the private schema
5 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
6 | -- SET search_path = admin, pg_temp;
7 | AS $$
8 | DECLARE
9 | retval json;
10 | MAILJET_API_KEY text;
11 | MAILJET_SECRET_KEY text;
12 | BEGIN
13 | SELECT value::text INTO MAILJET_API_KEY FROM private.keys WHERE key = 'MAILJET_API_KEY';
14 | IF NOT found THEN RAISE 'missing entry in private.keys: MAILJET_API_KEY'; END IF;
15 | SELECT value::text INTO MAILJET_SECRET_KEY FROM private.keys WHERE key = 'MAILJET_SECRET_KEY';
16 | IF NOT found THEN RAISE 'missing entry in private.keys: MAILJET_SECRET_KEY'; END IF;
17 |
18 | SELECT
19 | * INTO retval
20 | FROM
21 | http
22 | ((
23 | 'POST',
24 | 'https://api.mailjet.com/v3.1/send',
25 | ARRAY[http_header ('Authorization',
26 | --'Basic ' || encode((MAILJET_API_KEY || ':' || MAILJET_SECRET_KEY)::bytea, 'base64'::text))],
27 | 'Basic ' || regexp_replace(encode((MAILJET_API_KEY || ':' || MAILJET_SECRET_KEY)::bytea, 'base64')::text, '\s', '', 'g')
28 | )],
29 | 'application/json',
30 | json_build_object(
31 | 'Messages', json_build_array(
32 | json_build_object(
33 | 'From', json_build_object(
34 | 'Email', message->>'sender',
35 | 'Name', message->>'sender'
36 | ),
37 | 'To', json_build_array(
38 | json_build_object(
39 | 'Email', message->>'recipient',
40 | 'Name', message->>'recipient'
41 | )
42 | ),
43 | 'Subject', message->>'subject',
44 | 'TextPart', message->>'text_body',
45 | 'HTMLPart', message->>'html_body' --,
46 | --'CustomID', message->>'messageid'
47 | )
48 | )
49 | )::text
50 |
51 | ));
52 | -- if the message table exists,
53 | -- and the response from the mail server contains an id
54 | -- and the message from the mail server starts wtih 'Queued'
55 | -- mark this message as 'queued' in our message table, otherwise leave it as 'ready'
56 |
57 | IF (SELECT to_regclass('public.messages')) IS NOT NULL AND
58 | retval::text = '200' THEN
59 | UPDATE public.messages SET status = 'queued' WHERE id = (message->>'messageid')::UUID;
60 | ELSE
61 | RAISE 'error sending message with mailjet: %',retval;
62 | END IF;
63 |
64 | RETURN retval;
65 | END;
66 | $$;
67 | -- Do not allow this function to be called by public users (or called at all from the client)
68 | REVOKE EXECUTE on function public.send_email_mailjet FROM PUBLIC;
69 |
70 | /*
71 | curl -s \
72 | -X POST \
73 | --user "MAILJET_API_KEY:MAILJET_SECRET_KEY" \
74 | https://api.mailjet.com/v3.1/send \
75 | -H 'Content-Type: application/json' \
76 | -d '{
77 | "Messages":[
78 | {
79 | "From": {
80 | "Email": "from@email.com",
81 | "Name": "from@email.com"
82 | },
83 | "To": [
84 | {
85 | "Email": "to@email.com",
86 | "Name": "to@email.com"
87 | }
88 | ],
89 | "Subject": "My first Mailjet email",
90 | "TextPart": "Greetings from Mailjet.",
91 | "HTMLPart": "Dear passenger 1, welcome to Mailjet!
May the delivery force be with you!",
92 | "CustomID": "AppGettingStartedTest"
93 | }
94 | ]
95 | }'
96 | */
97 |
--------------------------------------------------------------------------------
/02E_send_email_mailersend.sql:
--------------------------------------------------------------------------------
1 | --drop function send_email_mailersend;
2 | CREATE OR REPLACE FUNCTION public.send_email_mailersend (message JSONB)
3 | RETURNS json
4 | LANGUAGE plpgsql
5 | SECURITY DEFINER -- required in order to read keys in the private schema
6 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
7 | -- SET search_path = admin, pg_temp;
8 | AS $$
9 | DECLARE
10 | retval json;
11 | MAILERSEND_API_TOKEN text;
12 | BEGIN
13 | SELECT value::text INTO MAILERSEND_API_TOKEN FROM private.keys WHERE key = 'MAILERSEND_API_TOKEN';
14 | IF NOT found THEN RAISE 'missing entry in private.keys: MAILERSEND_API_TOKEN'; END IF;
15 |
16 | SELECT
17 | * INTO retval
18 | FROM
19 | http
20 | ((
21 | 'POST',
22 | 'https://api.mailersend.com/v1/email',
23 | ARRAY[http_header ('Authorization',
24 | 'Bearer ' || MAILERSEND_API_TOKEN
25 | ), http_header ('X-Requested-With', 'XMLHttpRequest')],
26 | 'application/json',
27 | json_build_object(
28 | 'from', json_build_object(
29 | 'email', message->>'sender'
30 | ),
31 | 'to', json_build_array(
32 | json_build_object(
33 | 'email', message->>'recipient'
34 | )
35 | ),
36 | 'subject', message->>'subject',
37 | 'text', message->>'text_body',
38 | 'html', message->>'html_body' --,
39 | --'CustomID', message->>'messageid'
40 | )::text
41 |
42 | ));
43 | -- if the message table exists,
44 | -- and the response from the mail server contains an id
45 | -- and the message from the mail server starts wtih 'Queued'
46 | -- mark this message as 'queued' in our message table, otherwise leave it as 'ready'
47 |
48 | IF (SELECT to_regclass('public.messages')) IS NOT NULL AND
49 | retval::text = '202' THEN
50 | UPDATE public.messages SET status = 'queued' WHERE id = (message->>'messageid')::UUID;
51 | ELSE
52 | RAISE 'error sending message with mailersend: %',retval;
53 | END IF;
54 |
55 | RETURN retval;
56 | END;
57 | $$;
58 | -- Do not allow this function to be called by public users (or called at all from the client)
59 | REVOKE EXECUTE on function public.send_email_mailersend FROM PUBLIC;
60 |
61 | /*
62 |
63 | curl -X POST \
64 | https://api.mailersend.com/v1/email \
65 | -H 'Content-Type: application/json' \
66 | -H 'X-Requested-With: XMLHttpRequest' \
67 | -H 'Authorization: Bearer {place your token here without brackets}' \
68 | -d '{
69 | "from": {
70 | "email": "your@email.com"
71 | },
72 | "to": [
73 | {
74 | "email": "your@email.com"
75 | }
76 | ],
77 | "subject": "Hello from MailerSend!",
78 | "text": "Greetings from the team, you got this message through MailerSend.",
79 | "html": "Greetings from the team, you got this message through MailerSend."
80 | }'
81 |
82 |
83 |
84 | */
85 |
--------------------------------------------------------------------------------
/02_send_email_message.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | *
3 | * Function: send_email_message
4 | *
5 | * low level function to send email message
6 | *
7 | ************************************************************/
8 | CREATE EXTENSION IF NOT EXISTS HTTP;
9 | -- drop function send_email_message;
10 | CREATE OR REPLACE FUNCTION public.send_email_message (message JSONB)
11 | RETURNS json
12 | LANGUAGE plpgsql
13 | -- SECURITY DEFINER -- required in order to read keys in the private schema
14 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
15 | -- SET search_path = admin, pg_temp;
16 | AS $$
17 | DECLARE
18 | -- variable declaration
19 | email_provider text := 'mailgun'; -- 'mailgun', 'sendgrid', 'sendinblue', 'mailjet', 'mailersend'
20 | retval json;
21 | messageid text;
22 | BEGIN
23 |
24 |
25 | IF message->'text_body' IS NULL AND message->'html_body' IS NULL THEN RAISE 'message.text_body or message.html_body is required'; END IF;
26 |
27 | IF message->'text_body' IS NULL THEN
28 | select message || jsonb_build_object('text_body',message->>'html_body') into message;
29 | END IF;
30 |
31 | IF message->'html_body' IS NULL THEN
32 | select message || jsonb_build_object('html_body',message->>'text_body') into message;
33 | END IF;
34 |
35 | IF message->'recipient' IS NULL THEN RAISE 'message.recipient is required'; END IF;
36 | IF message->'sender' IS NULL THEN RAISE 'message.sender is required'; END IF;
37 | IF message->'subject' IS NULL THEN RAISE 'message.subject is required'; END IF;
38 |
39 | IF message->'messageid' IS NULL AND (SELECT to_regclass('public.messages')) IS NOT NULL THEN
40 | -- messages table exists, so save this message in the messages table
41 | INSERT INTO public.messages(recipient, sender, cc, bcc, subject, text_body, html_body, status, log)
42 | VALUES (message->'recipient', message->'sender', message->'cc', message->'bcc', message->'subject', message->'text_body', message->'html_body', 'ready', '[]'::jsonb) RETURNING id INTO messageid;
43 | select message || jsonb_build_object('messageid',messageid) into message;
44 | END IF;
45 |
46 | EXECUTE 'SELECT send_email_' || email_provider || '($1)' INTO retval USING message;
47 | -- SELECT send_email_mailgun(message) INTO retval;
48 | -- SELECT send_email_sendgrid(message) INTO retval;
49 |
50 | RETURN retval;
51 | END;
52 | $$;
53 | -- Do not allow this function to be called by public users (or called at all from the client)
54 | REVOKE EXECUTE on function public.send_email_message FROM PUBLIC;
55 |
56 | -- To allow, say, authenticated users to call this function, you would use:
57 | -- GRANT EXECUTE ON FUNCTION public.send_email_message TO authenticated;
58 |
59 |
60 |
--------------------------------------------------------------------------------
/03_setup_messages_table.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | * Create the messages table
3 | ************************************************************/
4 | CREATE TABLE if not exists public.messages
5 | (
6 | id uuid primary key default gen_random_uuid(),
7 | recipient text,
8 | sender text,
9 | cc text,
10 | bcc text,
11 | subject text,
12 | text_body text,
13 | html_body text,
14 | created timestamp with time zone DEFAULT CURRENT_TIMESTAMP,
15 | status text,
16 | deliveryresult jsonb,
17 | deliverysignature jsonb,
18 | log jsonb
19 | );
20 | ALTER TABLE public.messages OWNER TO postgres;
21 | ALTER TABLE public.messages ENABLE ROW LEVEL SECURITY;
22 | -- Turn off all access to the messages table by default
23 | CREATE POLICY "messages delete policy" ON public.messages FOR DELETE USING (false);
24 | CREATE POLICY "messages insert policy" ON public.messages FOR INSERT WITH CHECK (false);
25 | CREATE POLICY "messages select policy" ON public.messages FOR SELECT USING (false);
26 | CREATE POLICY "messages update policy" ON public.messages FOR UPDATE USING (false) WITH CHECK (false);
27 |
28 |
--------------------------------------------------------------------------------
/04A_setup_mailgun_web_hooks.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | *
3 | * Function: mailgun_webhook
4 | *
5 | * This is the function that is called when a webhook is received from Mailgun.
6 | *
7 | * Mailgun web hook
8 | * Paste the URL below into all of the MailGun WebHook entries
9 | * https://.supabase.co/rest/v1/rpc/mailgun_webhook?apikey=
10 | *
11 | ************************************************************/
12 | CREATE OR REPLACE FUNCTION public.mailgun_webhook("event-data" jsonb, "signature" jsonb)
13 | returns text
14 | language plpgsql
15 | security definer
16 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
17 | -- SET search_path = admin, pg_temp;
18 | as
19 | $$
20 | declare
21 | messageid text;
22 | begin
23 | select "event-data"->'user-variables'->>'messageid'::text into messageid;
24 |
25 | update public.messages
26 | set
27 | deliverysignature = signature,
28 | deliveryresult = "event-data",
29 | status = "event-data"->>'event'::text,
30 | log = COALESCE(log, '[]'::jsonb) || "event-data"
31 |
32 | where messages.id = messageid::uuid;
33 |
34 | return 'ok';
35 | end;
36 | $$
37 | /************************************************************/
38 |
39 | /************************************************************
40 | *
41 | * Function: create_mailgun_webhook
42 | *
43 | * create, replace, or delete a single mailgun webook
44 | *
45 | * This function updates a single Mailgun WebHook by calling the Mailgun API.
46 | *
47 | ************************************************************/
48 | create or replace function public.create_mailgun_webhook("hook_name" text, "mode" text)
49 | returns text
50 | language plpgsql
51 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
52 | -- SET search_path = admin, pg_temp;
53 | as
54 | $$
55 | declare
56 | -- variable declaration
57 | retval text;
58 | MAILGUN_DOMAIN text;
59 | MAILGUN_API_KEY text;
60 | webhooks jsonb;
61 | MAILGUN_WEBHOOK_URL text;
62 | begin
63 | select value::text into MAILGUN_WEBHOOK_URL from private.keys where key = 'MAILGUN_WEBHOOK_URL';
64 | if not found then
65 | raise 'missing entry in private.keys: MAILGUN_WEBHOOK_URL';
66 | end if;
67 | select value::text into MAILGUN_DOMAIN from private.keys where key = 'MAILGUN_DOMAIN';
68 | if not found then
69 | raise 'missing entry in private.keys: MAILGUN_DOMAIN';
70 | end if;
71 | select value::text into MAILGUN_API_KEY from private.keys where key = 'MAILGUN_API_KEY';
72 | if not found then
73 | raise 'missing entry in private.keys: MAILGUN_API_KEY';
74 | end if;
75 |
76 | if mode = 'CREATE' then
77 | SELECT content into retval FROM http(
78 | (
79 | 'POST',
80 | 'https://api.mailgun.net/v3/domains/' || MAILGUN_DOMAIN || '/webhooks',
81 | ARRAY[http_header('Authorization','Basic ' || encode(MAILGUN_API_KEY::bytea,'base64'::text))],
82 | 'application/x-www-form-urlencoded',
83 | 'id=' || urlencode(hook_name) ||
84 | '&url=' || urlencode(MAILGUN_WEBHOOK_URL)
85 | )
86 | );
87 | elseif mode = 'UPDATE' then
88 | SELECT content into retval FROM http(
89 | (
90 | 'PUT',
91 | 'https://api.mailgun.net/v3/domains/' || MAILGUN_DOMAIN || '/webhooks/' || hook_name,
92 | ARRAY[http_header('Authorization','Basic ' || encode(MAILGUN_API_KEY::bytea,'base64'::text))],
93 | 'application/x-www-form-urlencoded',
94 | 'url=' || urlencode(MAILGUN_WEBHOOK_URL)
95 | )
96 | );
97 | elseif mode = 'DELETE' then
98 | SELECT content into retval FROM http(
99 | (
100 | 'DELETE',
101 | 'https://api.mailgun.net/v3/domains/' || MAILGUN_DOMAIN || '/webhooks/' || hook_name,
102 | ARRAY[http_header('Authorization','Basic ' || encode(MAILGUN_API_KEY::bytea,'base64'::text))],
103 | 'application/x-www-form-urlencoded',
104 | 'url=' || urlencode(MAILGUN_WEBHOOK_URL)
105 | )
106 | );
107 | else
108 | raise 'unknown mode: %', mode;
109 | end if;
110 |
111 | return retval;
112 | end;
113 | $$
114 |
115 | /************************************************************
116 | *
117 | * Function: setup_mailgun_webhooks
118 | *
119 | * create or replace ALL mailgun webooks
120 | *
121 | * This function updates ALL Mailgun WebHooks by calling the Mailgun API.
122 | *
123 | * It calls create_mailgun_webhook to create webhooks for:
124 | *
125 | * clicked, delivered, opened, complained, permanent_fail, temporary_fail, and unsubscribed.
126 | *
127 | ************************************************************/
128 | create or replace function public.setup_mailgun_webhooks()
129 | returns text
130 | language plpgsql
131 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
132 | -- SET search_path = admin, pg_temp;
133 | as
134 | $$
135 | declare
136 | -- variable declaration
137 | MAILGUN_DOMAIN text;
138 | MAILGUN_API_KEY text;
139 | webhooks jsonb;
140 | MAILGUN_WEBHOOK_URL text;
141 | hook_result text;
142 | retval text;
143 | begin
144 | select value::text into MAILGUN_WEBHOOK_URL from private.keys where key = 'MAILGUN_WEBHOOK_URL';
145 | if not found then
146 | raise 'missing entry in private.keys: MAILGUN_WEBHOOK_URL';
147 | end if;
148 | select value::text into MAILGUN_DOMAIN from private.keys where key = 'MAILGUN_DOMAIN';
149 | if not found then
150 | raise 'missing entry in private.keys: MAILGUN_DOMAIN';
151 | end if;
152 | select value::text into MAILGUN_API_KEY from private.keys where key = 'MAILGUN_API_KEY';
153 | if not found then
154 | raise 'missing entry in private.keys: MAILGUN_API_KEY';
155 | end if;
156 | SELECT content into webhooks FROM http(
157 | (
158 | 'GET',
159 | -- replace(MAILGUN_URL_MESSAGES, '/messages', '/webhooks'),
160 | 'https://api.mailgun.net/v3/domains/' || MAILGUN_DOMAIN || '/webhooks',
161 | ARRAY[http_header('Authorization','Basic ' || encode(MAILGUN_API_KEY::bytea,'base64'::text))],
162 | 'application/x-www-form-urlencoded',
163 | ''
164 | )
165 | );
166 |
167 | select '[' into retval;
168 |
169 | if length(webhooks->'webhooks'->>'clicked') > 0 then
170 | select public.create_mailgun_webhook('clicked', 'UPDATE') into hook_result;
171 | else
172 | select public.create_mailgun_webhook('clicked', 'CREATE') into hook_result;
173 | end if;
174 |
175 | select retval || '{ "clicked": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
176 |
177 | if length(webhooks->'webhooks'->>'complained') > 0 then
178 | select public.create_mailgun_webhook('complained', 'UPDATE') into hook_result;
179 | else
180 | select public.create_mailgun_webhook('complained', 'CREATE') into hook_result;
181 | end if;
182 |
183 | select retval || ', { "complained": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
184 |
185 | if length(webhooks->'webhooks'->>'delivered') > 0 then
186 | select public.create_mailgun_webhook('delivered', 'UPDATE') into hook_result;
187 | else
188 | select public.create_mailgun_webhook('delivered', 'CREATE') into hook_result;
189 | end if;
190 |
191 | select retval || ', { "delivered": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
192 |
193 | if length(webhooks->'webhooks'->>'opened') > 0 then
194 | select public.create_mailgun_webhook('opened', 'UPDATE') into hook_result;
195 | else
196 | select public.create_mailgun_webhook('opened', 'CREATE') into hook_result;
197 | end if;
198 |
199 | select retval || ', { "opened": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
200 |
201 | if length(webhooks->'webhooks'->>'permanent_fail') > 0 then
202 | select public.create_mailgun_webhook('permanent_fail', 'UPDATE') into hook_result;
203 | else
204 | select public.create_mailgun_webhook('permanent_fail', 'CREATE') into hook_result;
205 | end if;
206 |
207 | select retval || ', { "permanent_fail": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
208 |
209 | if length(webhooks->'webhooks'->>'temporary_fail') > 0 then
210 | select public.create_mailgun_webhook('temporary_fail', 'UPDATE') into hook_result;
211 | else
212 | select public.create_mailgun_webhook('temporary_fail', 'CREATE') into hook_result;
213 | end if;
214 |
215 | select retval || ', { "temporary_fail": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
216 |
217 | if length(webhooks->'webhooks'->>'unsubscribed') > 0 then
218 | select public.create_mailgun_webhook('unsubscribed', 'UPDATE') into hook_result;
219 | else
220 | select public.create_mailgun_webhook('unsubscribed', 'CREATE') into hook_result;
221 | end if;
222 |
223 | select retval || ', { "unsubscribed": "' || (hook_result::jsonb->>'message'::text) || '" } ' into retval::text;
224 |
225 | select retval || ']' into retval;
226 |
227 | return retval::jsonb;
228 |
229 | end;
230 | $$
231 |
232 | /************************************************************
233 | *
234 | * Function: get_current_mailgun_webhooks
235 | *
236 | * list the status of all mailgun webhooks
237 | *
238 | ************************************************************/
239 |
240 | create or replace function public.get_current_mailgun_webhooks()
241 | returns jsonb
242 | language plpgsql
243 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'. abort
244 | -- SET search_path = admin, pg_temp;
245 | as
246 | $$
247 | declare
248 | -- variable declaration
249 | MAILGUN_DOMAIN text;
250 | MAILGUN_API_KEY text;
251 | retval jsonb;
252 | begin
253 |
254 | select value::text into MAILGUN_DOMAIN from private.keys where key = 'MAILGUN_DOMAIN';
255 | if not found then
256 | raise 'missing entry in private.keys: MAILGUN_DOMAIN';
257 | end if;
258 | select value::text into MAILGUN_API_KEY from private.keys where key = 'MAILGUN_API_KEY';
259 | if not found then
260 | raise 'missing entry in private.keys: MAILGUN_API_KEY';
261 | end if;
262 |
263 | SELECT content into retval FROM http(
264 | (
265 | 'GET',
266 | -- replace(MAILGUN_URL_MESSAGES, '/messages', '/webhooks'),
267 | 'https://api.mailgun.net/v3/domains/' || MAILGUN_DOMAIN || '/webhooks',
268 | ARRAY[http_header('Authorization','Basic ' || encode(MAILGUN_API_KEY::bytea,'base64'::text))],
269 | 'application/x-www-form-urlencoded',
270 | ''
271 | )
272 | );
273 |
274 | return retval::jsonb;
275 |
276 | end;
277 | $$
278 |
279 |
280 | /*
281 | Webhook testing and troubleshooting:
282 |
283 | webhooks:
284 | clicked
285 | complained
286 | delivered
287 | opened
288 | permanent_fail
289 | temporary_fail
290 | unsubscribed
291 |
292 | get webhooks
293 | curl -s --user "api:key-xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx" "https://api.mailgun.net/v3/domains/MY_DOMAIN/webhooks"
294 |
295 | create webhook
296 | curl -s --user 'api:YOUR_API_KEY' \
297 | https://api.mailgun.net/v3/domains/YOUR_DOMAIN_NAME/webhooks \
298 | -F id='clicked' \
299 | -F url='https://YOUR_SUPABASE_URL/rest/v1/rpc/mailgun_webhook?apikey=YOUR_PUBLIC_SUPABASE_KEY'
300 |
301 | update webhook
302 | curl -s --user 'api:YOUR_API_KEY' -X PUT \
303 | https://api.mailgun.net/v3/domains/YOUR_DOMAIN_NAME/webhooks/clicked \
304 | -F url='https://your_domain,com/v1/clicked'
305 |
306 | delete webhook
307 | curl -s --user 'api:YOUR_API_KEY' -X DELETE \
308 | https://api.mailgun.net/v3/domains/YOUR_DOMAIN_NAME/webhooks/clicked
309 |
310 | */
311 |
--------------------------------------------------------------------------------
/04B_setup_sendgrid_web_hooks.sql:
--------------------------------------------------------------------------------
1 | -- TODO
--------------------------------------------------------------------------------
/04C_setup_sendinblue_web_hooks.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE FUNCTION public.sendinblue_webhook(jsonb)
2 | returns text
3 | security definer
4 | language plpgsql
5 | as
6 | $_$
7 | begin
8 | update public.messages
9 | set
10 | status = ($1->>'event'),
11 | log = COALESCE(log, '[]'::jsonb) || $1
12 | where messages.id = ($1->'tags'->>0)::uuid;
13 | return 'ok';
14 | end;
15 | $_$;
16 |
17 | /*
18 | {
19 | "event":"delivered",
20 | "id":428172,
21 | "date":"2021-08-25 06:43:06",
22 | "ts":1629866586,
23 | "message-id":"<202108251532.75384645670@smtp-relay.mailin.fr>",
24 | "email":"user@.com",
25 | "ts_event":1229366586,
26 | "subject":"Sendinblue webhook test",
27 | "tag":"[\"5026b7c2-67a8-40d8-b08f-5bb9148bf665\"]",
28 | "sending_ip":"111.111.111.111",
29 | "ts_epoch":1629898986496,
30 | "tags":["5026b7c2-67a8-40d8-b08f-5bb9148bf665"]}
31 |
32 | */
--------------------------------------------------------------------------------
/04D_setup_mailjet_web_hooks.sql:
--------------------------------------------------------------------------------
1 | -- TODO
--------------------------------------------------------------------------------
/04E_setup_mailersend_web_hooks.sql:
--------------------------------------------------------------------------------
1 | -- TODO
--------------------------------------------------------------------------------
/05_create_email_message.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | *
3 | * Function: create_email_message(message JSON)
4 | *
5 | * create a message in the messages table
6 | *
7 | {
8 | recipient: "", -- REQUIRED
9 | sender: "", -- REQUIRED
10 | cc: "",
11 | bcc: "",
12 | subject: "", -- REQUIRED
13 | text_body: "", -- one of: text_body OR html_body is REQUIRED
14 | html_body: "" -- both can be sent but one of them is REQUIRED
15 | }
16 | returns: uuid (as text) of newly inserted message
17 | ************************************************************/
18 | create or replace function public.create_email_message(message JSON)
19 | returns text
20 | language plpgsql
21 | -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
22 | -- SET search_path = admin, pg_temp;
23 | as
24 | $$
25 | declare
26 | -- variable declaration
27 | recipient text;
28 | sender text;
29 | cc text;
30 | bcc text;
31 | subject text;
32 | text_body text;
33 | html_body text;
34 | retval text;
35 | begin
36 | /*
37 | if not exists (message->>'recipient') then
38 | RAISE INFO 'messages.recipient missing';
39 | end if
40 | */
41 | select message->>'recipient',
42 | message->>'sender',
43 | message->>'cc',
44 | message->>'bcc',
45 | message->>'subject',
46 | message->>'text_body',
47 | message->>'html_body' into recipient, sender, cc, bcc, subject, text_body, html_body;
48 |
49 | if coalesce(sender, '') = '' then
50 | -- select 'no sender' into retval;
51 | RAISE EXCEPTION 'message.sender missing';
52 | elseif coalesce(recipient, '') = '' then
53 | RAISE EXCEPTION 'message.recipient missing';
54 | elseif coalesce(subject, '') = '' then
55 | RAISE EXCEPTION 'message.subject missing';
56 | elseif coalesce(text_body, '') = '' and coalesce(html_body, '') = '' then
57 | RAISE EXCEPTION 'message.text_body and message.html_body are both missing';
58 | end if;
59 |
60 | if coalesce(text_body, '') = '' then
61 | select html_body into text_body;
62 | elseif coalesce(html_body, '') = '' then
63 | select text_body into html_body;
64 | end if;
65 |
66 | insert into public.messages(recipient, sender, cc, bcc, subject, text_body, html_body, status, log)
67 | values (recipient, sender, cc, bcc, subject, text_body, html_body, 'ready', '[]'::jsonb) returning id into retval;
68 |
69 | return retval;
70 | end;
71 | $$
72 |
--------------------------------------------------------------------------------
/99_(future)_setup_templates.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | *
3 | * Message Template System requires:
4 | * SupaScript: https://github.com/burggraf/SupaScript
5 | *
6 | ************************************************************/
7 |
8 |
9 | /************************************************************
10 | *
11 | * Function: prepare_message
12 | *
13 | * grab a template from the message_templates table by name,
14 | * send it a block of JSONB data, and have Mustache send you
15 | * a rendered block of HTML
16 | *
17 | ************************************************************/
18 | create or replace function prepare_message(template_name text, merge_data jsonb)
19 | returns text as $$
20 |
21 | const Mustache = require('https://unpkg.com/mustache@latest', false);
22 |
23 | const result = sql("select * from message_templates where name = $1 limit 1",[template_name]);
24 | if (result.length > 0) {
25 | template = result[0].template;
26 | return Mustache.render(template, merge_data);
27 | } else {
28 | return 'Template not found: ' + template_name;
29 | }
30 |
31 | $$ language plv8;
32 |
--------------------------------------------------------------------------------
/Mail_Providers/Mailersend.md:
--------------------------------------------------------------------------------
1 | # using supabase-mailer with Mailersend
2 |
3 | ## Step 1: Setup your private keys
4 |
5 | Execute the following code in a SQL Query window:
6 |
7 | ```sql
8 | INSERT INTO private.keys (key, value) values ('MAILERSEND_API_TOKEN', 'aaaaaaaaaa');
9 | ```
10 | Where:
11 | `aaaaaaaaaa` is your Mailersend API Token
12 |
13 | ## Step 2: Create the `send_email_message` function
14 |
15 | Run the `SQL` code contained in [02_send_email_message.sql](02_send_email_message.sql) in a query window to create the PostgreSQL function. NOTE: You must modify this function for Mailersend. See the line:
16 | ```sql
17 | email_provider text := 'mailersend';
18 | ```
19 |
20 | ## Step 2A: Create the `send_email_mailersend` function
21 | Run the `SQL` code contained in [02E_send_email_mailersend.sql](../02E_send_email_mailersend.sql) in a query window to create the PostgreSQL function.
22 |
23 | ## Send a test message
24 |
25 | You can send a test message from a query window like this:
26 |
27 | ```sql
28 | select send_email_message('{
29 | "sender": "sender@mydomain.com",
30 | "recipient": "recipient@somewhere.com",
31 | "subject": "This is a test message from my Supabase app!",
32 | "html_body": "This message was sent from PostgreSQL using Supabase and Mailersend."
33 | }');
34 | ```
35 | If you've got everything setup correctly, you'll get a JSON object back with the Provider's response, such as:
36 | ```
37 | 200
38 | ```
39 |
40 | At this point, you have everything you need to send messages. If you want to track your messages, read on.
41 |
42 | ## Step 3: (Optional) Create the messages table (for tracking messages)
43 |
44 | Run the `SQL` code from [03_setup_messages_table.sql](../03_setup_messages_table.sql) in a query window to create the table that will store your email messages. When the `send_email_message` function senses that this table exists, it will store your messages in this table automatically when you send them.
45 |
46 | ## Step 4: (Optional) Webhooks for tracking messages
47 |
48 | This step is not yet implemented.
49 |
50 | ## Step 5: (Optional) Create messages to be sent later
51 |
52 | This is completely optional, but if your workflow calls for you to create messages to be sent at a later time (say, according to a schedule, or triggered from another event or table update) you can use the `create_email_message` function.
53 |
54 | Run the `SQL` code in [05_create_email_message.sql](../05_create_email_message.sql) in a query window. Now you can create messages in the messages table like this:
55 |
56 | ```sql
57 | select create_email_message('{
58 | "sender": "sender@mydomain.com",
59 | "recipient": "recipient@somewhere.com",
60 | "subject": "This is a test message from my Supabase app!",
61 | "html_body": "This message was originally created as \"ready\" in the messages table, then sent later from Supabase using Mailersend."
62 | }');
63 | ```
64 |
65 | This will create a message in the messages table with `messages.status` = `ready` and it will return the `messageid` of the message it just created. To send the message, just call `send_email_message` later and pass it the `messageid` of this message. For example:
66 |
67 | ```sql
68 | select send_email_message('{
69 | "messageid": "7f5fd9b7-cacb-4949-b8d4-a0398fa382e7"
70 | }');
71 | ```
72 |
73 |
--------------------------------------------------------------------------------
/Mail_Providers/Mailgun.md:
--------------------------------------------------------------------------------
1 | # using supabase-mailer with Mailgun
2 |
3 | ## Step 1: Setup your private keys
4 |
5 | Execute the following code in a SQL Query window:
6 |
7 | ```sql
8 | INSERT INTO private.keys (key, value) values ('MAILGUN_DOMAIN', 'aaaaaaaaaa');
9 | INSERT INTO private.keys (key, value) values ('MAILGUN_API_KEY', 'bbbbbbbbbbb');
10 | INSERT INTO private.keys (key, value) values ('MAILGUN_WEBHOOK_URL',
11 | 'https://ccccccc@supabase.io/rest/v1/rpc/mailgun_webhook?apikey=ddddddddddddd');
12 | ```
13 | Where:
14 | `aaaaaaaaaa` is your Mailgun Domain
15 | `bbbbbbbbbbb` is your Mailgun API Key
16 | `ccccccc@supabase.io` is your Supabase API URL
17 | `ddddddddddddd` is your Supabase ANON (Public) API Key
18 |
19 | The last `INSERT` statement is optional -- if you're not using webhooks to track email messages you don't need it.
20 |
21 | ### API KEY NOTES
22 | Pay careful attention to your Mailgun API Key, it needs to be in the following format:
23 | ```
24 | api:key-xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx
25 | ```
26 | so you may need to add the `api:` part to the front of your key.
27 |
28 |
29 | ## Step 2: Create the `send_email_message` function
30 |
31 | Run the `SQL` code contained in [02_send_email_message.sql](02_send_email_message.sql) in a query window to create the PostgreSQL function. NOTE: You must modify this function for Mailgun. See the line:
32 | ```sql
33 | email_provider text := 'mailgun';
34 | ```
35 |
36 | ## Step 2A: Create the `send_email_mailgun` function
37 | Run the `SQL` code contained in [02A_send_email_mailgun.sql](../02A_send_email_mailgun.sql) in a query window to create the PostgreSQL function.
38 |
39 | ## Send a test message
40 |
41 | You can send a test message from a query window like this:
42 |
43 | ```sql
44 | select send_email_message('{
45 | "sender": "sender@mydomain.com",
46 | "recipient": "recipient@somewhere.com",
47 | "subject": "This is a test message from my Supabase app!",
48 | "html_body": "This message was sent from PostgreSQL using Supabase and Mailgun."
49 | }');
50 | ```
51 | If you've got everything setup correctly, you'll get a JSON object back with the Provider's response, such as:
52 | ```
53 | {"id":"<20210809140930.1.A3374464DBAD3C45A@my.mailgun.domain.com>","message":"Queued. Thank you."}
54 | ```
55 |
56 | At this point, you have everything you need to send messages. If you want to track your messages, read on.
57 |
58 | ## Step 3: (Optional) Create the messages table (for tracking messages)
59 |
60 | Run the `SQL` code from [03_setup_messages_table.sql](../03_setup_messages_table.sql) in a query window to create the table that will store your email messages. When the `send_email_message` function senses that this table exists, it will store your messages in this table automatically when you send them.
61 |
62 | ## Step 4: (Optional) Set up Webhooks
63 |
64 | Run the `SQL` code from [04_setup_mailgun_web_hooks.sql](../04_setup_mailgun_web_hooks.sql) to create the functions that will automatically configure your webhooks using the Mailgun API.
65 |
66 | This will create the following functions:
67 |
68 | - `setup_mailgun_webhooks` -- this is the only function you need to run, and just one time (see below)
69 | - `create_mailgun_webhook` -- this is called by the function above to create each individual webhook
70 | - `mailgun_webhook` -- this is called directly by Mailgun each time the status of one of your messages changes
71 | - `get_current_mailgun_webhooks` -- this is just for debugging -- it goes out to the Mailgun API to see if your webbooks are set up at the Mailgun site
72 |
73 | ## Step 4A: (Optional) Automatically set up your webhooks at Mailgun using the API
74 | ```sql
75 | select setup_mailgun_webhooks();
76 | ```
77 |
78 | This sets up all your webhooks. If you want to verify if your webhooks are set up at Mailgun, you can go to the Mailgun site and see them there, or check them with:
79 |
80 | ```sql
81 | select get_current_mailgun_webhooks();
82 | ```
83 |
84 | ## Step 5: (Optional) Create messages to be sent later
85 |
86 | This is completely optional, but if your workflow calls for you to create messages to be sent at a later time (say, according to a schedule, or triggered from another event or table update) you can use the `create_email_message` function.
87 |
88 | Run the `SQL` code in [05_create_email_message.sql](../05_create_email_message.sql) in a query window. Now you can create messages in the messages table like this:
89 |
90 | ```sql
91 | select create_email_message('{
92 | "sender": "sender@mydomain.com",
93 | "recipient": "recipient@somewhere.com",
94 | "subject": "This is a test message from my Supabase app!",
95 | "html_body": "This message was originally created as \"ready\" in the messages table, then sent later from Supabase using Mailgun."
96 | }');
97 | ```
98 |
99 | This will create a message in the messages table with `messages.status` = `ready` and it will return the `messageid` of the message it just created. To send the message, just call `send_email_message` later and pass it the `messageid` of this message. For example:
100 |
101 | ```sql
102 | select send_email_message('{
103 | "messageid": "7f5fd9b7-cacb-4949-b8d4-a0398fa382e7"
104 | }');
105 | ```
106 |
107 | ## Tracking your messages
108 |
109 | If you've set up your `web hooks`, and you've created the `messages` table, then your message statuses will be updated automatically in the `messages` table. You can watch the status of your message go from `ready` to `queued` to `delivered` to `opened` to `clicked`. See [Mailgun: Tracking Messages](https://documentation.mailgun.com/en/latest/user_manual.html#tracking-messages).
110 |
111 | In addition to the `status` field of the messages table changing, a `log` record is added to the array of events in the `log` field of the messages table. `log` is a `JSONB` column, so every event for the message is logged individually, along with all the data that comes back from Mailgun, including the timestamp of the event.
112 |
--------------------------------------------------------------------------------
/Mail_Providers/Mailjet.md:
--------------------------------------------------------------------------------
1 | # using supabase-mailer with Mailjet
2 |
3 | ## Step 1: Setup your private keys
4 |
5 | Execute the following code in a SQL Query window:
6 |
7 | ```sql
8 | INSERT INTO private.keys (key, value) values ('MAILJET_API_KEY', 'aaaaaaaaaa');
9 | INSERT INTO private.keys (key, value) values ('MAILJET_SECRET_KEY', 'bbbbbbbbbb');
10 | ```
11 | Where:
12 | `aaaaaaaaaa` is your Mailjet API Key
13 | `bbbbbbbbbb` is your Mailjet SECRET Key
14 |
15 | ## Step 2: Create the `send_email_message` function
16 |
17 | Run the `SQL` code contained in [02_send_email_message.sql](02_send_email_message.sql) in a query window to create the PostgreSQL function. NOTE: You must modify this function for Mailjet. See the line:
18 | ```sql
19 | email_provider text := 'mailjet';
20 | ```
21 |
22 | ## Step 2A: Create the `send_email_mailjet` function
23 | Run the `SQL` code contained in [02D_send_email_mailjet.sql](../02D_send_email_mailjet.sql) in a query window to create the PostgreSQL function.
24 |
25 | ## Send a test message
26 |
27 | You can send a test message from a query window like this:
28 |
29 | ```sql
30 | select send_email_message('{
31 | "sender": "sender@mydomain.com",
32 | "recipient": "recipient@somewhere.com",
33 | "subject": "This is a test message from my Supabase app!",
34 | "html_body": "This message was sent from PostgreSQL using Supabase and Mailjet."
35 | }');
36 | ```
37 | If you've got everything setup correctly, you'll get a JSON object back with the Provider's response, such as:
38 | ```
39 | 200
40 | ```
41 |
42 | At this point, you have everything you need to send messages. If you want to track your messages, read on.
43 |
44 | ## Step 3: (Optional) Create the messages table (for tracking messages)
45 |
46 | Run the `SQL` code from [03_setup_messages_table.sql](../03_setup_messages_table.sql) in a query window to create the table that will store your email messages. When the `send_email_message` function senses that this table exists, it will store your messages in this table automatically when you send them.
47 |
48 | ## Step 4: (Optional) Webhooks for tracking messages
49 |
50 | This step is not yet implemented.
51 |
52 | ## Step 5: (Optional) Create messages to be sent later
53 |
54 | This is completely optional, but if your workflow calls for you to create messages to be sent at a later time (say, according to a schedule, or triggered from another event or table update) you can use the `create_email_message` function.
55 |
56 | Run the `SQL` code in [05_create_email_message.sql](../05_create_email_message.sql) in a query window. Now you can create messages in the messages table like this:
57 |
58 | ```sql
59 | select create_email_message('{
60 | "sender": "sender@mydomain.com",
61 | "recipient": "recipient@somewhere.com",
62 | "subject": "This is a test message from my Supabase app!",
63 | "html_body": "This message was originally created as \"ready\" in the messages table, then sent later from Supabase using Mailjet."
64 | }');
65 | ```
66 |
67 | This will create a message in the messages table with `messages.status` = `ready` and it will return the `messageid` of the message it just created. To send the message, just call `send_email_message` later and pass it the `messageid` of this message. For example:
68 |
69 | ```sql
70 | select send_email_message('{
71 | "messageid": "7f5fd9b7-cacb-4949-b8d4-a0398fa382e7"
72 | }');
73 | ```
74 |
75 |
--------------------------------------------------------------------------------
/Mail_Providers/Sendgrid.md:
--------------------------------------------------------------------------------
1 | # using supabase-mailer with Sendgrid
2 |
3 | ## Step 1: Setup your private keys
4 |
5 | Execute the following code in a SQL Query window:
6 |
7 | ```sql
8 | INSERT INTO private.keys (key, value) values ('SENDGRID_API_KEY', 'aaaaaaaaaa');
9 | ```
10 | Where:
11 | `aaaaaaaaaa` is your Sendgrid API Key
12 |
13 | ## Step 2: Create the `send_email_message` function
14 |
15 | Run the `SQL` code contained in [02_send_email_message.sql](02_send_email_message.sql) in a query window to create the PostgreSQL function. NOTE: You must modify this function for Sendgrid. See the line:
16 | ```sql
17 | email_provider text := 'sendgrid';
18 | ```
19 |
20 | ## Step 2A: Create the `send_email_sendgrid` function
21 | Run the `SQL` code contained in [02D_send_email_sendgrid.sql](../02D_send_email_sendgrid.sql) in a query window to create the PostgreSQL function.
22 |
23 | ## Send a test message
24 |
25 | You can send a test message from a query window like this:
26 |
27 | ```sql
28 | select send_email_message('{
29 | "sender": "sender@mydomain.com",
30 | "recipient": "recipient@somewhere.com",
31 | "subject": "This is a test message from my Supabase app!",
32 | "html_body": "This message was sent from PostgreSQL using Supabase and Sendgrid."
33 | }');
34 | ```
35 | If you've got everything setup correctly, you'll get a JSON object back with the Provider's response, such as:
36 | ```
37 | 200
38 | ```
39 |
40 | At this point, you have everything you need to send messages. If you want to track your messages, read on.
41 |
42 | ## Step 3: (Optional) Create the messages table (for tracking messages)
43 |
44 | Run the `SQL` code from [03_setup_messages_table.sql](../03_setup_messages_table.sql) in a query window to create the table that will store your email messages. When the `send_email_message` function senses that this table exists, it will store your messages in this table automatically when you send them.
45 |
46 | ## Step 4: (Optional) Webhooks for tracking messages
47 |
48 | This step is not yet implemented.
49 |
50 | ## Step 5: (Optional) Create messages to be sent later
51 |
52 | This is completely optional, but if your workflow calls for you to create messages to be sent at a later time (say, according to a schedule, or triggered from another event or table update) you can use the `create_email_message` function.
53 |
54 | Run the `SQL` code in [05_create_email_message.sql](../05_create_email_message.sql) in a query window. Now you can create messages in the messages table like this:
55 |
56 | ```sql
57 | select create_email_message('{
58 | "sender": "sender@mydomain.com",
59 | "recipient": "recipient@somewhere.com",
60 | "subject": "This is a test message from my Supabase app!",
61 | "html_body": "This message was originally created as \"ready\" in the messages table, then sent later from Supabase using Sendgrid."
62 | }');
63 | ```
64 |
65 | This will create a message in the messages table with `messages.status` = `ready` and it will return the `messageid` of the message it just created. To send the message, just call `send_email_message` later and pass it the `messageid` of this message. For example:
66 |
67 | ```sql
68 | select send_email_message('{
69 | "messageid": "7f5fd9b7-cacb-4949-b8d4-a0398fa382e7"
70 | }');
71 | ```
72 |
73 |
--------------------------------------------------------------------------------
/Mail_Providers/Sendinblue.md:
--------------------------------------------------------------------------------
1 | # using supabase-mailer with Sendinblue
2 |
3 | ## Step 1: Setup your private keys
4 |
5 | Execute the following code in a SQL Query window:
6 |
7 | ```sql
8 | INSERT INTO private.keys (key, value) values ('SENDINBLUE_API_KEY', '[SENDINBLUE_API_KEY]');
9 | ```
10 | Where:
11 | `[SENDINBLUE_API_KEY]` is your Sendinblue API Key
12 |
13 | ## Step 2: Create the `send_email_message` function
14 |
15 | Run the `SQL` code contained in [02_send_email_message.sql](02_send_email_message.sql) in a query window to create the PostgreSQL function. NOTE: You must modify this function for Sendinblue. See the line:
16 | ```sql
17 | email_provider text := 'sendinblue';
18 | ```
19 |
20 | ## Step 2A: Create the `send_email_sendinblue` function
21 | Run the `SQL` code contained in [02D_send_email_sendinblue.sql](../02D_send_email_sendinblue.sql) in a query window to create the PostgreSQL function.
22 |
23 | ## Send a test message
24 |
25 | You can send a test message from a query window like this:
26 |
27 | ```sql
28 | select send_email_message('{
29 | "sender": "sender@mydomain.com",
30 | "recipient": "recipient@somewhere.com",
31 | "subject": "This is a test message from my Supabase app!",
32 | "html_body": "This message was sent from PostgreSQL using Supabase and Sendinblue."
33 | }');
34 | ```
35 | If you've got everything setup correctly, you'll get a JSON object back with the Provider's response, such as:
36 | ```
37 | 200
38 | ```
39 |
40 | At this point, you have everything you need to send messages. If you want to track your messages, read on.
41 |
42 | ## Step 3: (Optional) Create the messages table (for tracking messages)
43 |
44 | Run the `SQL` code from [03_setup_messages_table.sql](../03_setup_messages_table.sql) in a query window to create the table that will store your email messages. When the `send_email_message` function senses that this table exists, it will store your messages in this table automatically when you send them.
45 |
46 | ## Step 4: (Optional) Webhooks for tracking messages
47 |
48 | This step is not yet implemented.
49 |
50 | ## Step 5: (Optional) Create messages to be sent later
51 |
52 | This is completely optional, but if your workflow calls for you to create messages to be sent at a later time (say, according to a schedule, or triggered from another event or table update) you can use the `create_email_message` function.
53 |
54 | Run the `SQL` code in [05_create_email_message.sql](../05_create_email_message.sql) in a query window. Now you can create messages in the messages table like this:
55 |
56 | ```sql
57 | select create_email_message('{
58 | "sender": "sender@mydomain.com",
59 | "recipient": "recipient@somewhere.com",
60 | "subject": "This is a test message from my Supabase app!",
61 | "html_body": "This message was originally created as \"ready\" in the messages table, then sent later from Supabase using Sendinblue."
62 | }');
63 | ```
64 |
65 | This will create a message in the messages table with `messages.status` = `ready` and it will return the `messageid` of the message it just created. To send the message, just call `send_email_message` later and pass it the `messageid` of this message. For example:
66 |
67 | ```sql
68 | select send_email_message('{
69 | "messageid": "7f5fd9b7-cacb-4949-b8d4-a0398fa382e7"
70 | }');
71 | ```
72 |
73 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # supabase-mailer
2 | Send and track email from Supabase / PostgreSQL using a Transactional Email Provider (Mailgun, Sendgrid, Sendinblue, Mailjet, Mailersend)
3 |
4 | ## Features
5 | - Send an email message using the API of a Transactional Email Provider
6 | - [Mailgun](https://mailgun.com)
7 | - [Sendgrid](https://sendgrid.com)
8 | - [Sendinblue](https://sendinblue.com)
9 | - [Mailjet](https://mailjet.com)
10 | - [Mailersend](https://mailersend.com)
11 | - Create and store an outgoing email messages in a PostgreSQL table
12 | - Send a `message` from the `messages` table using the API of your selected mail provider
13 | - Webooks can track the status of your messages and update your `messages` table based on various events
14 | - Mailgun
15 | - Mailgun webhooks can be set up automatically using their API -- just call the PostgreSQL setup function
16 | - Mailgun events:
17 | - temporary_fail
18 | - permanent_fail
19 | - delivered
20 | - opened
21 | - clicked
22 | - complained
23 | - unsubscribed
24 | - Other providers coming soon...
25 |
26 | ## Requirements
27 | - Supabase account (free tier is fine)
28 | - Sending messages should work with any PostgreSQL database (no Supabase account required)
29 | - Webhooks require a Supabase account so the webhooks have a server (Postgrest) to post event messages to
30 | - A Transactional Email Provider account (most have a free tier available)
31 | - supported providers: Mailgun, Sendgrid, Sendinblue, Mailjet
32 |
33 | ## Setup for Mail Providers:
34 |
35 | See: [Mailgun Setup](./Mail_Providers/Mailgun.md)
36 |
37 | See: [Mailjet Setup](./Mail_Providers/Mailjet.md)
38 |
39 | See: [Sendgrid Setup](./Mail_Providers/Sendgrid.md)
40 |
41 | See: [Sendinblue Setup](./Mail_Providers/Sendinblue.md)
42 |
43 | See: [Mailersend Setup](./Mail_Providers/Mailersend.md)
44 |
--------------------------------------------------------------------------------