queries.sql 37 KB

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