queries.sql 44 KB

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