queries.sql 30 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723
  1. -- subscribers
  2. -- name: get-subscriber
  3. -- Get a single subscriber by id or UUID.
  4. SELECT * FROM subscribers WHERE CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END;
  5. -- name: subscriber-exists
  6. -- Check if a subscriber exists by id or UUID.
  7. SELECT exists (SELECT true FROM subscribers WHERE CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END);
  8. -- name: get-subscribers-by-emails
  9. -- Get subscribers by emails.
  10. SELECT * FROM subscribers WHERE email=ANY($1);
  11. -- name: get-subscriber-lists
  12. WITH sub AS (
  13. SELECT id FROM subscribers WHERE CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END
  14. )
  15. SELECT * FROM lists
  16. LEFT JOIN subscriber_lists ON (lists.id = subscriber_lists.list_id)
  17. WHERE subscriber_id = (SELECT id FROM sub)
  18. -- Optional list IDs or UUIDs to filter.
  19. AND (CASE WHEN $3::INT[] IS NOT NULL THEN id = ANY($3::INT[])
  20. WHEN $4::UUID[] IS NOT NULL THEN uuid = ANY($4::UUID[])
  21. ELSE TRUE
  22. END)
  23. AND (CASE WHEN $5 != '' THEN subscriber_lists.status = $5::subscription_status END)
  24. AND (CASE WHEN $6 != '' THEN lists.optin = $6::list_optin ELSE TRUE END);
  25. -- name: get-subscriber-lists-lazy
  26. -- Get lists associations of subscribers given a list of subscriber IDs.
  27. -- This query is used to lazy load given a list of subscriber IDs.
  28. -- The query returns results in the same order as the given subscriber IDs, and for non-existent subscriber IDs,
  29. -- the query still returns a row with 0 values. Thus, for lazy loading, the application simply iterate on the results in
  30. -- the same order as the list of campaigns it would've queried and attach the results.
  31. WITH subs AS (
  32. SELECT subscriber_id, JSON_AGG(
  33. ROW_TO_JSON(
  34. (SELECT l FROM (SELECT subscriber_lists.status AS subscription_status, lists.*) l)
  35. )
  36. ) AS lists FROM lists
  37. LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
  38. WHERE subscriber_lists.subscriber_id = ANY($1)
  39. GROUP BY subscriber_id
  40. )
  41. SELECT id as subscriber_id,
  42. COALESCE(s.lists, '[]') AS lists
  43. FROM (SELECT id FROM UNNEST($1) AS id) x
  44. LEFT JOIN subs AS s ON (s.subscriber_id = id)
  45. ORDER BY ARRAY_POSITION($1, id);
  46. -- name: insert-subscriber
  47. WITH sub AS (
  48. INSERT INTO subscribers (uuid, email, name, status, attribs)
  49. VALUES($1, $2, $3, $4, $5)
  50. returning id
  51. ),
  52. listIDs AS (
  53. SELECT id FROM lists WHERE
  54. (CASE WHEN ARRAY_LENGTH($6::INT[], 1) > 0 THEN id=ANY($6)
  55. ELSE uuid=ANY($7::UUID[]) END)
  56. ),
  57. subs AS (
  58. INSERT INTO subscriber_lists (subscriber_id, list_id, status)
  59. VALUES(
  60. (SELECT id FROM sub),
  61. UNNEST(ARRAY(SELECT id FROM listIDs)),
  62. (CASE WHEN $4='blacklisted' THEN 'unsubscribed'::subscription_status ELSE 'unconfirmed' END)
  63. )
  64. ON CONFLICT (subscriber_id, list_id) DO UPDATE
  65. SET updated_at=NOW()
  66. )
  67. SELECT id from sub;
  68. -- name: upsert-subscriber
  69. -- Upserts a subscriber where existing subscribers get their names and attributes overwritten.
  70. -- The status field is only updated when $6 = 'override_status'.
  71. WITH sub AS (
  72. INSERT INTO subscribers (uuid, email, name, attribs)
  73. VALUES($1, $2, $3, $4)
  74. ON CONFLICT (email) DO UPDATE
  75. SET name=$3,
  76. attribs=$4,
  77. updated_at=NOW()
  78. RETURNING uuid, id
  79. ),
  80. subs AS (
  81. INSERT INTO subscriber_lists (subscriber_id, list_id)
  82. VALUES((SELECT id FROM sub), UNNEST($5::INT[]))
  83. ON CONFLICT (subscriber_id, list_id) DO UPDATE
  84. SET updated_at=NOW()
  85. )
  86. SELECT uuid, id from sub;
  87. -- name: upsert-blacklist-subscriber
  88. -- Upserts a subscriber where the update will only set the status to blacklisted
  89. -- unlike upsert-subscribers where name and attributes are updated. In addition, all
  90. -- existing subscriptions are marked as 'unsubscribed'.
  91. -- This is used in the bulk importer.
  92. WITH sub AS (
  93. INSERT INTO subscribers (uuid, email, name, attribs, status)
  94. VALUES($1, $2, $3, $4, 'blacklisted')
  95. ON CONFLICT (email) DO UPDATE SET status='blacklisted', updated_at=NOW()
  96. RETURNING id
  97. )
  98. UPDATE subscriber_lists SET status='unsubscribed', updated_at=NOW()
  99. WHERE subscriber_id = (SELECT id FROM sub);
  100. -- name: update-subscriber
  101. -- Updates a subscriber's data, and given a list of list_ids, inserts subscriptions
  102. -- for them while deleting existing subscriptions not in the list.
  103. WITH s AS (
  104. UPDATE subscribers SET
  105. email=(CASE WHEN $2 != '' THEN $2 ELSE email END),
  106. name=(CASE WHEN $3 != '' THEN $3 ELSE name END),
  107. status=(CASE WHEN $4 != '' THEN $4::subscriber_status ELSE status END),
  108. attribs=(CASE WHEN $5::TEXT != '' THEN $5::JSONB ELSE attribs END),
  109. updated_at=NOW()
  110. WHERE id = $1 RETURNING id
  111. ),
  112. d AS (
  113. DELETE FROM subscriber_lists WHERE subscriber_id = $1 AND list_id != ALL($6)
  114. )
  115. INSERT INTO subscriber_lists (subscriber_id, list_id, status)
  116. VALUES(
  117. (SELECT id FROM s),
  118. UNNEST($6),
  119. (CASE WHEN $4='blacklisted' THEN 'unsubscribed'::subscription_status ELSE 'unconfirmed' END)
  120. )
  121. ON CONFLICT (subscriber_id, list_id) DO UPDATE
  122. SET status = (CASE WHEN $4='blacklisted' THEN 'unsubscribed'::subscription_status ELSE subscriber_lists.status END);
  123. -- name: delete-subscribers
  124. -- Delete one or more subscribers by ID or UUID.
  125. DELETE FROM subscribers WHERE CASE WHEN ARRAY_LENGTH($1::INT[], 1) > 0 THEN id = ANY($1) ELSE uuid = ANY($2::UUID[]) END;
  126. -- name: blacklist-subscribers
  127. WITH b AS (
  128. UPDATE subscribers SET status='blacklisted', updated_at=NOW()
  129. WHERE id = ANY($1::INT[])
  130. )
  131. UPDATE subscriber_lists SET status='unsubscribed', updated_at=NOW()
  132. WHERE subscriber_id = ANY($1::INT[]);
  133. -- name: add-subscribers-to-lists
  134. INSERT INTO subscriber_lists (subscriber_id, list_id)
  135. (SELECT a, b FROM UNNEST($1::INT[]) a, UNNEST($2::INT[]) b)
  136. ON CONFLICT (subscriber_id, list_id) DO NOTHING;
  137. -- name: delete-subscriptions
  138. DELETE FROM subscriber_lists
  139. WHERE (subscriber_id, list_id) = ANY(SELECT a, b FROM UNNEST($1::INT[]) a, UNNEST($2::INT[]) b);
  140. -- name: confirm-subscription-optin
  141. WITH subID AS (
  142. SELECT id FROM subscribers WHERE uuid = $1::UUID
  143. ),
  144. listIDs AS (
  145. SELECT id FROM lists WHERE uuid = ANY($2::UUID[])
  146. )
  147. UPDATE subscriber_lists SET status='confirmed', updated_at=NOW()
  148. WHERE subscriber_id = (SELECT id FROM subID) AND list_id = ANY(SELECT id FROM listIDs);
  149. -- name: unsubscribe-subscribers-from-lists
  150. UPDATE subscriber_lists SET status='unsubscribed', updated_at=NOW()
  151. WHERE (subscriber_id, list_id) = ANY(SELECT a, b FROM UNNEST($1::INT[]) a, UNNEST($2::INT[]) b);
  152. -- name: unsubscribe
  153. -- Unsubscribes a subscriber given a campaign UUID (from all the lists in the campaign) and the subscriber UUID.
  154. -- If $3 is TRUE, then all subscriptions of the subscriber is blacklisted
  155. -- and all existing subscriptions, irrespective of lists, unsubscribed.
  156. WITH lists AS (
  157. SELECT list_id FROM campaign_lists
  158. LEFT JOIN campaigns ON (campaign_lists.campaign_id = campaigns.id)
  159. WHERE campaigns.uuid = $1
  160. ),
  161. sub AS (
  162. UPDATE subscribers SET status = (CASE WHEN $3 IS TRUE THEN 'blacklisted' ELSE status END)
  163. WHERE uuid = $2 RETURNING id
  164. )
  165. UPDATE subscriber_lists SET status = 'unsubscribed' WHERE
  166. subscriber_id = (SELECT id FROM sub) AND status != 'unsubscribed' AND
  167. -- If $3 is false, unsubscribe from the campaign's lists, otherwise all lists.
  168. CASE WHEN $3 IS FALSE THEN list_id = ANY(SELECT list_id FROM lists) ELSE list_id != 0 END;
  169. -- privacy
  170. -- name: export-subscriber-data
  171. WITH prof AS (
  172. SELECT id, uuid, email, name, attribs, status, created_at, updated_at FROM subscribers WHERE
  173. CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END
  174. ),
  175. subs AS (
  176. SELECT subscriber_lists.status AS subscription_status,
  177. (CASE WHEN lists.type = 'private' THEN 'Private list' ELSE lists.name END) as name,
  178. lists.type, subscriber_lists.created_at
  179. FROM lists
  180. LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
  181. WHERE subscriber_lists.subscriber_id = (SELECT id FROM prof)
  182. ),
  183. views AS (
  184. SELECT subject as campaign, COUNT(subscriber_id) as views FROM campaign_views
  185. LEFT JOIN campaigns ON (campaigns.id = campaign_views.campaign_id)
  186. WHERE subscriber_id = (SELECT id FROM prof)
  187. GROUP BY campaigns.id ORDER BY id
  188. ),
  189. clicks AS (
  190. SELECT url, COUNT(subscriber_id) as clicks FROM link_clicks
  191. LEFT JOIN links ON (links.id = link_clicks.link_id)
  192. WHERE subscriber_id = (SELECT id FROM prof)
  193. GROUP BY links.id ORDER BY id
  194. )
  195. SELECT (SELECT email FROM prof) as email,
  196. COALESCE((SELECT JSON_AGG(t) FROM prof t), '{}') AS profile,
  197. COALESCE((SELECT JSON_AGG(t) FROM subs t), '[]') AS subscriptions,
  198. COALESCE((SELECT JSON_AGG(t) FROM views t), '[]') AS campaign_views,
  199. COALESCE((SELECT JSON_AGG(t) FROM clicks t), '[]') AS link_clicks;
  200. -- Partial and RAW queries used to construct arbitrary subscriber
  201. -- queries for segmentation follow.
  202. -- name: query-subscribers
  203. -- raw: true
  204. -- Unprepared statement for issuring arbitrary WHERE conditions for
  205. -- searching subscribers. While the results are sliced using offset+limit,
  206. -- there's a COUNT() OVER() that still returns the total result count
  207. -- for pagination in the frontend, albeit being a field that'll repeat
  208. -- with every resultant row.
  209. SELECT COUNT(*) OVER () AS total, subscribers.* FROM subscribers
  210. LEFT JOIN subscriber_lists
  211. ON (
  212. -- Optional list filtering.
  213. (CASE WHEN CARDINALITY($1::INT[]) > 0 THEN true ELSE false END)
  214. AND subscriber_lists.subscriber_id = subscribers.id
  215. )
  216. WHERE subscriber_lists.list_id = ALL($1::INT[])
  217. %s
  218. ORDER BY $2 DESC OFFSET $3 LIMIT $4;
  219. -- name: query-subscribers-template
  220. -- raw: true
  221. -- This raw query is reused in multiple queries (blacklist, add to list, delete)
  222. -- etc., so it's kept has a raw template to be injected into other raw queries,
  223. -- and for the same reason, it is not terminated with a semicolon.
  224. --
  225. -- All queries that embed this query should expect
  226. -- $1=true/false (dry-run or not) and $2=[]INT (option list IDs).
  227. -- That is, their positional arguments should start from $3.
  228. SELECT subscribers.id FROM subscribers
  229. LEFT JOIN subscriber_lists
  230. ON (
  231. -- Optional list filtering.
  232. (CASE WHEN CARDINALITY($2::INT[]) > 0 THEN true ELSE false END)
  233. AND subscriber_lists.subscriber_id = subscribers.id
  234. )
  235. WHERE subscriber_lists.list_id = ALL($2::INT[]) %s
  236. LIMIT (CASE WHEN $1 THEN 1 END)
  237. -- name: delete-subscribers-by-query
  238. -- raw: true
  239. WITH subs AS (%s)
  240. DELETE FROM subscribers WHERE id=ANY(SELECT id FROM subs);
  241. -- name: blacklist-subscribers-by-query
  242. -- raw: true
  243. WITH subs AS (%s),
  244. b AS (
  245. UPDATE subscribers SET status='blacklisted', updated_at=NOW()
  246. WHERE id = ANY(SELECT id FROM subs)
  247. )
  248. UPDATE subscriber_lists SET status='unsubscribed', updated_at=NOW()
  249. WHERE subscriber_id = ANY(SELECT id FROM subs);
  250. -- name: add-subscribers-to-lists-by-query
  251. -- raw: true
  252. WITH subs AS (%s)
  253. INSERT INTO subscriber_lists (subscriber_id, list_id)
  254. (SELECT a, b FROM UNNEST(ARRAY(SELECT id FROM subs)) a, UNNEST($3::INT[]) b)
  255. ON CONFLICT (subscriber_id, list_id) DO NOTHING;
  256. -- name: delete-subscriptions-by-query
  257. -- raw: true
  258. WITH subs AS (%s)
  259. DELETE FROM subscriber_lists
  260. WHERE (subscriber_id, list_id) = ANY(SELECT a, b FROM UNNEST(ARRAY(SELECT id FROM subs)) a, UNNEST($3::INT[]) b);
  261. -- name: unsubscribe-subscribers-from-lists-by-query
  262. -- raw: true
  263. WITH subs AS (%s)
  264. UPDATE subscriber_lists SET status='unsubscribed', updated_at=NOW()
  265. WHERE (subscriber_id, list_id) = ANY(SELECT a, b FROM UNNEST(ARRAY(SELECT id FROM subs)) a, UNNEST($3::INT[]) b);
  266. -- lists
  267. -- name: get-lists
  268. SELECT COUNT(*) OVER () AS total, lists.*, COUNT(subscriber_lists.subscriber_id) AS subscriber_count
  269. FROM lists LEFT JOIN subscriber_lists
  270. ON (subscriber_lists.list_id = lists.id AND subscriber_lists.status != 'unsubscribed')
  271. WHERE ($1 = 0 OR id = $1)
  272. GROUP BY lists.id ORDER BY lists.created_at OFFSET $2 LIMIT (CASE WHEN $3 = 0 THEN NULL ELSE $3 END);
  273. -- name: get-lists-by-optin
  274. -- Can have a list of IDs or a list of UUIDs.
  275. SELECT * FROM lists WHERE (CASE WHEN $1 != '' THEN optin=$1::list_optin ELSE TRUE END) AND
  276. (CASE WHEN $2::INT[] IS NOT NULL THEN id = ANY($2::INT[])
  277. WHEN $3::UUID[] IS NOT NULL THEN uuid = ANY($3::UUID[])
  278. END) ORDER BY name;
  279. -- name: create-list
  280. INSERT INTO lists (uuid, name, type, optin, tags) VALUES($1, $2, $3, $4, $5) RETURNING id;
  281. -- name: update-list
  282. UPDATE lists SET
  283. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  284. type=(CASE WHEN $3 != '' THEN $3::list_type ELSE type END),
  285. optin=(CASE WHEN $4 != '' THEN $4::list_optin ELSE optin END),
  286. tags=(CASE WHEN ARRAY_LENGTH($5::VARCHAR(100)[], 1) > 0 THEN $5 ELSE tags END),
  287. updated_at=NOW()
  288. WHERE id = $1;
  289. -- name: update-lists-date
  290. UPDATE lists SET updated_at=NOW() WHERE id = ANY($1);
  291. -- name: delete-lists
  292. DELETE FROM lists WHERE id = ALL($1);
  293. -- campaigns
  294. -- name: create-campaign
  295. -- This creates the campaign and inserts campaign_lists relationships.
  296. WITH campLists AS (
  297. -- Get the list_ids and their optin statuses for the campaigns found in the previous step.
  298. SELECT id AS list_id, campaign_id, optin FROM lists
  299. INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
  300. WHERE id=ANY($12::INT[])
  301. ),
  302. tpl AS (
  303. -- If there's no template_id given, use the defualt template.
  304. SELECT (CASE WHEN $11 = 0 THEN id ELSE $11 END) AS id FROM templates WHERE is_default IS TRUE
  305. ),
  306. counts AS (
  307. SELECT COALESCE(COUNT(id), 0) as to_send, COALESCE(MAX(id), 0) as max_sub_id
  308. FROM subscribers
  309. LEFT JOIN campLists ON (campLists.campaign_id = ANY($12::INT[]))
  310. LEFT JOIN subscriber_lists ON (
  311. subscriber_lists.status != 'unsubscribed' AND
  312. subscribers.id = subscriber_lists.subscriber_id AND
  313. subscriber_lists.list_id = campLists.list_id AND
  314. -- For double opt-in lists, consider only 'confirmed' subscriptions. For single opt-ins,
  315. -- any status except for 'unsubscribed' (already excluded above) works.
  316. (CASE WHEN campLists.optin = 'double' THEN subscriber_lists.status = 'confirmed' ELSE true END)
  317. )
  318. WHERE subscriber_lists.list_id=ANY($12::INT[])
  319. AND subscribers.status='enabled'
  320. ),
  321. camp AS (
  322. INSERT INTO campaigns (uuid, type, name, subject, from_email, body, content_type, send_at, tags, messenger, template_id, to_send, max_subscriber_id)
  323. SELECT $1, $2, $3, $4, $5, $6, $7, $8, $9, $10, (SELECT id FROM tpl), (SELECT to_send FROM counts), (SELECT max_sub_id FROM counts)
  324. RETURNING id
  325. )
  326. INSERT INTO campaign_lists (campaign_id, list_id, list_name)
  327. (SELECT (SELECT id FROM camp), id, name FROM lists WHERE id=ANY($12::INT[]))
  328. RETURNING (SELECT id FROM camp);
  329. -- name: query-campaigns
  330. -- Here, 'lists' is returned as an aggregated JSON array from campaign_lists because
  331. -- the list reference may have been deleted.
  332. -- While the results are sliced using offset+limit,
  333. -- there's a COUNT() OVER() that still returns the total result count
  334. -- for pagination in the frontend, albeit being a field that'll repeat
  335. -- with every resultant row.
  336. SELECT COUNT(*) OVER () AS total, campaigns.*, (
  337. SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(l)), '[]') FROM (
  338. SELECT COALESCE(campaign_lists.list_id, 0) AS id,
  339. campaign_lists.list_name AS name
  340. FROM campaign_lists WHERE campaign_lists.campaign_id = campaigns.id
  341. ) l
  342. ) AS lists
  343. FROM campaigns
  344. WHERE ($1 = 0 OR id = $1)
  345. AND status=ANY(CASE WHEN ARRAY_LENGTH($2::campaign_status[], 1) != 0 THEN $2::campaign_status[] ELSE ARRAY[status] END)
  346. AND ($3 = '' OR (to_tsvector(name || subject) @@ to_tsquery($3)))
  347. ORDER BY campaigns.updated_at DESC OFFSET $4 LIMIT $5;
  348. -- name: get-campaign
  349. SELECT campaigns.*,
  350. COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body
  351. FROM campaigns
  352. LEFT JOIN templates ON (templates.id = campaigns.template_id)
  353. WHERE CASE WHEN $1 > 0 THEN campaigns.id = $1 ELSE uuid = $2 END;
  354. -- name: get-campaign-stats
  355. -- This query is used to lazy load campaign stats (views, counts, list of lists) given a list of campaign IDs.
  356. -- The query returns results in the same order as the given campaign IDs, and for non-existent campaign IDs,
  357. -- the query still returns a row with 0 values. Thus, for lazy loading, the application simply iterate on the results in
  358. -- the same order as the list of campaigns it would've queried and attach the results.
  359. WITH lists AS (
  360. SELECT campaign_id, JSON_AGG(JSON_BUILD_OBJECT('id', list_id, 'name', list_name)) AS lists FROM campaign_lists
  361. WHERE campaign_id = ANY($1) GROUP BY campaign_id
  362. ), views AS (
  363. SELECT campaign_id, COUNT(campaign_id) as num FROM campaign_views
  364. WHERE campaign_id = ANY($1)
  365. GROUP BY campaign_id
  366. ),
  367. clicks AS (
  368. SELECT campaign_id, COUNT(campaign_id) as num FROM link_clicks
  369. WHERE campaign_id = ANY($1)
  370. GROUP BY campaign_id
  371. )
  372. SELECT id as campaign_id,
  373. COALESCE(v.num, 0) AS views,
  374. COALESCE(c.num, 0) AS clicks,
  375. COALESCE(l.lists, '[]') AS lists
  376. FROM (SELECT id FROM UNNEST($1) AS id) x
  377. LEFT JOIN lists AS l ON (l.campaign_id = id)
  378. LEFT JOIN views AS v ON (v.campaign_id = id)
  379. LEFT JOIN clicks AS c ON (c.campaign_id = id)
  380. ORDER BY ARRAY_POSITION($1, id);
  381. -- name: get-campaign-for-preview
  382. SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body,
  383. (
  384. SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(l)), '[]') FROM (
  385. SELECT COALESCE(campaign_lists.list_id, 0) AS id,
  386. campaign_lists.list_name AS name
  387. FROM campaign_lists WHERE campaign_lists.campaign_id = campaigns.id
  388. ) l
  389. ) AS lists
  390. FROM campaigns
  391. LEFT JOIN templates ON (templates.id = campaigns.template_id)
  392. WHERE campaigns.id = $1;
  393. -- name: get-campaign-status
  394. SELECT id, status, to_send, sent, started_at, updated_at
  395. FROM campaigns
  396. WHERE status=$1;
  397. -- name: next-campaigns
  398. -- Retreives campaigns that are running (or scheduled and the time's up) and need
  399. -- to be processed. It updates the to_send count and max_subscriber_id of the campaign,
  400. -- that is, the total number of subscribers to be processed across all lists of a campaign.
  401. -- Thus, it has a sideaffect.
  402. -- In addition, it finds the max_subscriber_id, the upper limit across all lists of
  403. -- a campaign. This is used to fetch and slice subscribers for the campaign in next-subscriber-campaigns.
  404. WITH camps AS (
  405. -- Get all running campaigns and their template bodies (if the template's deleted, the default template body instead)
  406. SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body
  407. FROM campaigns
  408. LEFT JOIN templates ON (templates.id = campaigns.template_id)
  409. WHERE (status='running' OR (status='scheduled' AND NOW() >= campaigns.send_at))
  410. AND NOT(campaigns.id = ANY($1::INT[]))
  411. ),
  412. campLists AS (
  413. -- Get the list_ids and their optin statuses for the campaigns found in the previous step.
  414. SELECT id AS list_id, campaign_id, optin FROM lists
  415. INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
  416. WHERE campaign_lists.campaign_id = ANY(SELECT id FROM camps)
  417. ),
  418. counts AS (
  419. -- For each campaign above, get the total number of subscribers and the max_subscriber_id
  420. -- across all its lists.
  421. SELECT id AS campaign_id,
  422. COUNT(DISTINCT(subscriber_lists.subscriber_id)) AS to_send,
  423. COALESCE(MAX(subscriber_lists.subscriber_id), 0) AS max_subscriber_id
  424. FROM camps
  425. LEFT JOIN campLists ON (campLists.campaign_id = camps.id)
  426. LEFT JOIN subscriber_lists ON (
  427. subscriber_lists.list_id = campLists.list_id AND
  428. (CASE
  429. -- For optin campaigns, only e-mail 'unconfirmed' subscribers belonging to 'double' optin lists.
  430. WHEN camps.type = 'optin' THEN subscriber_lists.status = 'unconfirmed' AND campLists.optin = 'double'
  431. -- For regular campaigns with double optin lists, only e-mail 'confirmed' subscribers.
  432. WHEN campLists.optin = 'double' THEN subscriber_lists.status = 'confirmed'
  433. -- For regular campaigns with non-double optin lists, e-mail everyone
  434. -- except unsubscribed subscribers.
  435. ELSE subscriber_lists.status != 'unsubscribed'
  436. END)
  437. )
  438. GROUP BY camps.id
  439. ),
  440. u AS (
  441. -- For each campaign, update the to_send count and set the max_subscriber_id.
  442. UPDATE campaigns AS ca
  443. SET to_send = co.to_send,
  444. status = (CASE WHEN status != 'running' THEN 'running' ELSE status END),
  445. max_subscriber_id = co.max_subscriber_id,
  446. started_at=(CASE WHEN ca.started_at IS NULL THEN NOW() ELSE ca.started_at END)
  447. FROM (SELECT * FROM counts) co
  448. WHERE ca.id = co.campaign_id
  449. )
  450. SELECT * FROM camps;
  451. -- name: next-campaign-subscribers
  452. -- Returns a batch of subscribers in a given campaign starting from the last checkpoint
  453. -- (last_subscriber_id). Every fetch updates the checkpoint and the sent count, which means
  454. -- every fetch returns a new batch of subscribers until all rows are exhausted.
  455. WITH camps AS (
  456. SELECT last_subscriber_id, max_subscriber_id, type
  457. FROM campaigns
  458. WHERE id=$1 AND status='running'
  459. ),
  460. campLists AS (
  461. SELECT id AS list_id, optin FROM lists
  462. INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
  463. WHERE campaign_lists.campaign_id = $1
  464. ),
  465. subs AS (
  466. SELECT DISTINCT ON(subscribers.id) id AS uniq_id, subscribers.* FROM subscriber_lists
  467. INNER JOIN campLists ON (
  468. campLists.list_id = subscriber_lists.list_id
  469. )
  470. INNER JOIN subscribers ON (
  471. subscribers.status != 'blacklisted' AND
  472. subscribers.id = subscriber_lists.subscriber_id AND
  473. (CASE
  474. -- For optin campaigns, only e-mail 'unconfirmed' subscribers.
  475. WHEN (SELECT type FROM camps) = 'optin' THEN subscriber_lists.status = 'unconfirmed' AND campLists.optin = 'double'
  476. -- For regular campaigns with double optin lists, only e-mail 'confirmed' subscribers.
  477. WHEN campLists.optin = 'double' THEN subscriber_lists.status = 'confirmed'
  478. -- For regular campaigns with non-double optin lists, e-mail everyone
  479. -- except unsubscribed subscribers.
  480. ELSE subscriber_lists.status != 'unsubscribed'
  481. END)
  482. )
  483. WHERE subscriber_lists.status != 'unsubscribed' AND
  484. id > (SELECT last_subscriber_id FROM camps) AND
  485. id <= (SELECT max_subscriber_id FROM camps)
  486. ORDER BY id LIMIT $2
  487. ),
  488. u AS (
  489. UPDATE campaigns
  490. SET last_subscriber_id = (SELECT MAX(id) FROM subs),
  491. sent = sent + (SELECT COUNT(id) FROM subs),
  492. updated_at = NOW()
  493. WHERE (SELECT COUNT(id) FROM subs) > 0 AND id=$1
  494. )
  495. SELECT * FROM subs;
  496. -- name: get-one-campaign-subscriber
  497. SELECT * FROM subscribers
  498. LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id AND subscriber_lists.status != 'unsubscribed')
  499. WHERE subscriber_lists.list_id=ANY(
  500. SELECT list_id FROM campaign_lists where campaign_id=$1 AND list_id IS NOT NULL
  501. )
  502. ORDER BY RANDOM() LIMIT 1;
  503. -- name: update-campaign
  504. WITH camp AS (
  505. UPDATE campaigns SET
  506. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  507. subject=(CASE WHEN $3 != '' THEN $3 ELSE subject END),
  508. from_email=(CASE WHEN $4 != '' THEN $4 ELSE from_email END),
  509. body=(CASE WHEN $5 != '' THEN $5 ELSE body END),
  510. content_type=(CASE WHEN $6 != '' THEN $6::content_type ELSE content_type END),
  511. send_at=(CASE WHEN $8 THEN $7::TIMESTAMP WITH TIME ZONE WHEN NOT $8 THEN NULL ELSE send_at END),
  512. tags=(CASE WHEN ARRAY_LENGTH($9::VARCHAR(100)[], 1) > 0 THEN $9 ELSE tags END),
  513. template_id=(CASE WHEN $10 != 0 THEN $10 ELSE template_id END),
  514. updated_at=NOW()
  515. WHERE id = $1 RETURNING id
  516. ),
  517. d AS (
  518. -- Reset list relationships
  519. DELETE FROM campaign_lists WHERE campaign_id = $1 AND NOT(list_id = ANY($11))
  520. )
  521. INSERT INTO campaign_lists (campaign_id, list_id, list_name)
  522. (SELECT $1 as campaign_id, id, name FROM lists WHERE id=ANY($11::INT[]))
  523. ON CONFLICT (campaign_id, list_id) DO UPDATE SET list_name = EXCLUDED.list_name;
  524. -- name: update-campaign-counts
  525. UPDATE campaigns SET
  526. to_send=(CASE WHEN $2 != 0 THEN $2 ELSE to_send END),
  527. sent=(CASE WHEN $3 != 0 THEN $3 ELSE sent END),
  528. last_subscriber_id=(CASE WHEN $4 != 0 THEN $4 ELSE last_subscriber_id END),
  529. updated_at=NOW()
  530. WHERE id=$1;
  531. -- name: update-campaign-status
  532. UPDATE campaigns SET status=$2, updated_at=NOW() WHERE id = $1;
  533. -- name: delete-campaign
  534. DELETE FROM campaigns WHERE id=$1 AND (status = 'draft' OR status = 'scheduled');
  535. -- name: register-campaign-view
  536. WITH view AS (
  537. SELECT campaigns.id as campaign_id, subscribers.id AS subscriber_id FROM campaigns
  538. LEFT JOIN subscribers ON (subscribers.uuid = $2)
  539. WHERE campaigns.uuid = $1
  540. )
  541. INSERT INTO campaign_views (campaign_id, subscriber_id)
  542. VALUES((SELECT campaign_id FROM view), (SELECT subscriber_id FROM view));
  543. -- users
  544. -- name: get-users
  545. SELECT * FROM users WHERE $1 = 0 OR id = $1 OFFSET $2 LIMIT $3;
  546. -- name: create-user
  547. INSERT INTO users (email, name, password, type, status) VALUES($1, $2, $3, $4, $5) RETURNING id;
  548. -- name: update-user
  549. UPDATE users SET
  550. email=(CASE WHEN $2 != '' THEN $2 ELSE email END),
  551. name=(CASE WHEN $3 != '' THEN $3 ELSE name END),
  552. password=(CASE WHEN $4 != '' THEN $4 ELSE password END),
  553. type=(CASE WHEN $5 != '' THEN $5::user_type ELSE type END),
  554. status=(CASE WHEN $6 != '' THEN $6::user_status ELSE status END),
  555. updated_at=NOW()
  556. WHERE id = $1;
  557. -- name: delete-user
  558. -- Delete a user, except for the primordial super admin.
  559. DELETE FROM users WHERE $1 != 1 AND id=$1;
  560. -- templates
  561. -- name: get-templates
  562. -- Only if the second param ($2) is true, body is returned.
  563. SELECT id, name, (CASE WHEN $2 = false THEN body ELSE '' END) as body,
  564. is_default, created_at, updated_at
  565. FROM templates WHERE $1 = 0 OR id = $1
  566. ORDER BY created_at;
  567. -- name: create-template
  568. INSERT INTO templates (name, body) VALUES($1, $2) RETURNING id;
  569. -- name: update-template
  570. UPDATE templates SET
  571. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  572. body=(CASE WHEN $3 != '' THEN $3 ELSE body END),
  573. updated_at=NOW()
  574. WHERE id = $1;
  575. -- name: set-default-template
  576. WITH u AS (
  577. UPDATE templates SET is_default=true WHERE id=$1 RETURNING id
  578. )
  579. UPDATE templates SET is_default=false WHERE id != $1;
  580. -- name: delete-template
  581. -- Delete a template as long as there's more than one. One deletion, set all campaigns
  582. -- with that template to the default template instead.
  583. WITH tpl AS (
  584. DELETE FROM templates WHERE id = $1 AND (SELECT COUNT(id) FROM templates) > 1 AND is_default = false RETURNING id
  585. ),
  586. def AS (
  587. SELECT id FROM templates WHERE is_default = true LIMIT 1
  588. )
  589. UPDATE campaigns SET template_id = (SELECT id FROM def) WHERE (SELECT id FROM tpl) > 0 AND template_id = $1
  590. RETURNING (SELECT id FROM tpl);
  591. -- media
  592. -- name: insert-media
  593. INSERT INTO media (uuid, filename, thumb, width, height, created_at) VALUES($1, $2, $3, $4, $5, NOW());
  594. -- name: get-media
  595. SELECT * FROM media ORDER BY created_at DESC;
  596. -- name: delete-media
  597. DELETE FROM media WHERE id=$1 RETURNING filename;
  598. -- links
  599. -- name: create-link
  600. INSERT INTO links (uuid, url) VALUES($1, $2) ON CONFLICT (url) DO UPDATE SET url=EXCLUDED.url RETURNING uuid;
  601. -- name: register-link-click
  602. WITH link AS (
  603. SELECT url, links.id AS link_id, campaigns.id as campaign_id, subscribers.id AS subscriber_id FROM links
  604. LEFT JOIN campaigns ON (campaigns.uuid = $2)
  605. LEFT JOIN subscribers ON (subscribers.uuid = $3)
  606. WHERE links.uuid = $1
  607. )
  608. INSERT INTO link_clicks (campaign_id, subscriber_id, link_id)
  609. VALUES((SELECT campaign_id FROM link), (SELECT subscriber_id FROM link), (SELECT link_id FROM link))
  610. RETURNING (SELECT url FROM link);
  611. -- name: get-dashboard-charts
  612. WITH clicks AS (
  613. -- Clicks by day for the last 3 months
  614. SELECT JSON_AGG(ROW_TO_JSON(row))
  615. FROM (SELECT COUNT(*) AS count, created_at::DATE as date
  616. FROM link_clicks GROUP by date ORDER BY date DESC LIMIT 100
  617. ) row
  618. ),
  619. views AS (
  620. -- Views by day for the last 3 months
  621. SELECT JSON_AGG(ROW_TO_JSON(row))
  622. FROM (SELECT COUNT(*) AS count, created_at::DATE as date
  623. FROM campaign_views GROUP by date ORDER BY date DESC LIMIT 100
  624. ) row
  625. )
  626. SELECT JSON_BUILD_OBJECT('link_clicks', COALESCE((SELECT * FROM clicks), '[]'),
  627. 'campaign_views', COALESCE((SELECT * FROM views), '[]'));
  628. -- name: get-dashboard-counts
  629. SELECT JSON_BUILD_OBJECT('subscribers', JSON_BUILD_OBJECT(
  630. 'total', (SELECT COUNT(*) FROM subscribers),
  631. 'blacklisted', (SELECT COUNT(*) FROM subscribers WHERE status='blacklisted'),
  632. 'orphans', (
  633. SELECT COUNT(id) FROM subscribers
  634. LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id)
  635. WHERE subscriber_lists.subscriber_id IS NULL
  636. )
  637. ),
  638. 'lists', JSON_BUILD_OBJECT(
  639. 'total', (SELECT COUNT(*) FROM lists),
  640. 'private', (SELECT COUNT(*) FROM lists WHERE type='private'),
  641. 'public', (SELECT COUNT(*) FROM lists WHERE type='public'),
  642. 'optin_single', (SELECT COUNT(*) FROM lists WHERE optin='single'),
  643. 'optin_double', (SELECT COUNT(*) FROM lists WHERE optin='double')
  644. ),
  645. 'campaigns', JSON_BUILD_OBJECT(
  646. 'total', (SELECT COUNT(*) FROM campaigns),
  647. 'by_status', (
  648. SELECT JSON_OBJECT_AGG (status, num) FROM
  649. (SELECT status, COUNT(*) AS num FROM campaigns GROUP BY status) r
  650. )
  651. ),
  652. 'messages', (SELECT SUM(sent) AS messages FROM campaigns));