queries.sql 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386
  1. -- subscribers
  2. -- name: get-subscriber
  3. -- Get a single subscriber by id or UUID.
  4. SELECT * FROM subscribers WHERE CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END;
  5. -- subscribers
  6. -- name: get-subscribers-by-emails
  7. -- Get subscribers by emails.
  8. SELECT * FROM subscribers WHERE email=ANY($1);
  9. -- name: get-subscriber-lists
  10. -- Get lists belonging to subscribers.
  11. SELECT lists.*, subscriber_lists.subscriber_id, subscriber_lists.status AS subscription_status FROM lists
  12. LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
  13. WHERE subscriber_lists.subscriber_id = ANY($1::INT[]);
  14. -- name: query-subscribers
  15. -- raw: true
  16. -- Unprepared statement for issuring arbitrary WHERE conditions.
  17. SELECT * FROM subscribers WHERE 1=1 %s order by updated_at DESC OFFSET %d LIMIT %d;
  18. -- name: query-subscribers-count
  19. -- raw: true
  20. SELECT COUNT(id) as num FROM subscribers WHERE 1=1 %s;
  21. -- name: query-subscribers-by-list
  22. -- raw: true
  23. -- Unprepared statement for issuring arbitrary WHERE conditions.
  24. SELECT subscribers.* FROM subscribers INNER JOIN subscriber_lists
  25. ON (subscriber_lists.subscriber_id = subscribers.id)
  26. WHERE subscriber_lists.list_id = %d
  27. %s
  28. ORDER BY id DESC OFFSET %d LIMIT %d;
  29. -- name: query-subscribers-by-list-count
  30. -- raw: true
  31. SELECT COUNT(subscribers.id) as num FROM subscribers INNER JOIN subscriber_lists
  32. ON (subscriber_lists.subscriber_id = subscribers.id)
  33. WHERE subscriber_lists.list_id = %d
  34. %s;
  35. -- name: upsert-subscriber
  36. -- In case of updates, if $6 (override_status) is true, only then, the existing
  37. -- value is overwritten with the incoming value. This is used for insertions and bulk imports.
  38. WITH s AS (
  39. INSERT INTO subscribers (uuid, email, name, status, attribs)
  40. VALUES($1, $2, $3, $4, $5) ON CONFLICT (email) DO UPDATE
  41. SET name=$3, status=(CASE WHEN $6 = true THEN $4 ELSE subscribers.status END),
  42. attribs=$5, updated_at=NOW()
  43. RETURNING id
  44. ) INSERT INTO subscriber_lists (subscriber_id, list_id)
  45. VALUES((SELECT id FROM s), UNNEST($7::INT[]) )
  46. ON CONFLICT (subscriber_id, list_id) DO NOTHING
  47. RETURNING subscriber_id;
  48. -- name: update-subscriber
  49. -- Updates a subscriber's data, and given a list of list_ids, inserts subscriptions
  50. -- for them while deleting existing subscriptions not in the list.
  51. WITH s AS (
  52. UPDATE subscribers SET
  53. email=(CASE WHEN $2 != '' THEN $2 ELSE email END),
  54. name=(CASE WHEN $3 != '' THEN $3 ELSE name END),
  55. status=(CASE WHEN $4 != '' THEN $4::subscriber_status ELSE status END),
  56. attribs=(CASE WHEN $5::TEXT != '' THEN $5::JSONB ELSE attribs END),
  57. updated_at=NOW()
  58. WHERE id = $1 RETURNING id
  59. ),
  60. d AS (
  61. DELETE FROM subscriber_lists WHERE subscriber_id = $1 AND list_id != ALL($6)
  62. )
  63. INSERT INTO subscriber_lists (subscriber_id, list_id)
  64. VALUES( (SELECT id FROM s), UNNEST($6) )
  65. ON CONFLICT (subscriber_id, list_id) DO NOTHING;
  66. -- name: delete-subscribers
  67. -- Delete one or more subscribers.
  68. DELETE FROM subscribers WHERE id = ALL($1);
  69. -- name: unsubscribe
  70. -- Unsubscribes a subscriber given a campaign UUID (from all the lists in the campaign) and the subscriber UUID.
  71. -- If $3 is TRUE, then all subscriptions of the subscriber is blacklisted
  72. -- and all existing subscriptions, irrespective of lists, unsubscribed.
  73. WITH lists AS (
  74. SELECT list_id FROM campaign_lists
  75. LEFT JOIN campaigns ON (campaign_lists.campaign_id = campaigns.id)
  76. WHERE campaigns.uuid = $1
  77. ),
  78. sub AS (
  79. UPDATE subscribers SET status = (CASE WHEN $3 IS TRUE THEN 'blacklisted' ELSE status END)
  80. WHERE uuid = $2 RETURNING id
  81. )
  82. UPDATE subscriber_lists SET status = 'unsubscribed' WHERE
  83. subscriber_id = (SELECT id FROM sub) AND status != 'unsubscribed' AND
  84. -- If $3 is false, unsubscribe from the campaign's lists, otherwise all lists.
  85. CASE WHEN $3 IS FALSE THEN list_id = ANY(SELECT list_id FROM lists) ELSE list_id != 0 END;
  86. -- name: query-subscribers-into-lists
  87. -- raw: true
  88. -- Unprepared statement for issuring arbitrary WHERE conditions and getting
  89. -- the resultant subscriber IDs into subscriber_lists.
  90. WITH subs AS (
  91. SELECT id FROM subscribers WHERE status != 'blacklisted' %s
  92. )
  93. INSERT INTO subscriber_lists (subscriber_id, list_id)
  94. (SELECT id, UNNEST($1::INT[]) FROM subs)
  95. ON CONFLICT (subscriber_id, list_id) DO NOTHING;
  96. -- lists
  97. -- name: get-lists
  98. SELECT lists.*, COUNT(subscriber_lists.subscriber_id) AS subscriber_count
  99. FROM lists LEFT JOIN subscriber_lists
  100. ON (subscriber_lists.list_id = lists.id AND subscriber_lists.status != 'unsubscribed')
  101. WHERE ($1 = 0 OR id = $1)
  102. GROUP BY lists.id ORDER BY lists.created_at;
  103. -- name: create-list
  104. INSERT INTO lists (uuid, name, type, tags) VALUES($1, $2, $3, $4) RETURNING id;
  105. -- name: update-list
  106. UPDATE lists SET
  107. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  108. type=(CASE WHEN $3 != '' THEN $3::list_type ELSE type END),
  109. tags=(CASE WHEN ARRAY_LENGTH($4::VARCHAR(100)[], 1) > 0 THEN $4 ELSE tags END),
  110. updated_at=NOW()
  111. WHERE id = $1;
  112. -- name: delete-lists
  113. DELETE FROM lists WHERE id = ALL($1);
  114. -- campaigns
  115. -- name: create-campaign
  116. -- This creates the campaign and inserts campaign_lists relationships.
  117. WITH counts AS (
  118. SELECT COUNT(id) as to_send, MAX(id) as max_sub_id
  119. FROM subscribers
  120. LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id)
  121. WHERE subscriber_lists.list_id=ANY($11::INT[])
  122. AND subscribers.status='enabled'
  123. ),
  124. camp AS (
  125. INSERT INTO campaigns (uuid, name, subject, from_email, body, content_type, send_at, tags, messenger, template_id, to_send, max_subscriber_id)
  126. SELECT $1, $2, $3, $4, $5, $6, $7, $8, $9, $10,
  127. (SELECT to_send FROM counts),
  128. (SELECT max_sub_id FROM counts)
  129. WHERE (SELECT COALESCE(MAX(to_send), 0) FROM counts) > 0
  130. RETURNING id
  131. )
  132. INSERT INTO campaign_lists (campaign_id, list_id, list_name)
  133. (SELECT (SELECT id FROM camp), id, name FROM lists WHERE id=ANY($11::INT[]))
  134. RETURNING (SELECT id FROM camp);
  135. -- name: get-campaigns
  136. -- Here, 'lists' is returned as an aggregated JSON array from campaign_lists because
  137. -- the list reference may have been deleted.
  138. SELECT campaigns.*, (
  139. SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(l)), '[]') FROM (
  140. SELECT COALESCE(campaign_lists.list_id, 0) AS id,
  141. campaign_lists.list_name AS name
  142. FROM campaign_lists WHERE campaign_lists.campaign_id = campaigns.id
  143. ) l
  144. ) AS lists
  145. FROM campaigns
  146. WHERE ($1 = 0 OR id = $1) AND status=(CASE WHEN $2 != '' THEN $2::campaign_status ELSE status END)
  147. ORDER BY created_at DESC OFFSET $3 LIMIT $4;
  148. -- name: get-campaign-for-preview
  149. SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body,
  150. (
  151. SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(l)), '[]') FROM (
  152. SELECT COALESCE(campaign_lists.list_id, 0) AS id,
  153. campaign_lists.list_name AS name
  154. FROM campaign_lists WHERE campaign_lists.campaign_id = campaigns.id
  155. ) l
  156. ) AS lists
  157. FROM campaigns
  158. LEFT JOIN templates ON (templates.id = campaigns.template_id)
  159. WHERE campaigns.id = $1;
  160. -- name: get-campaign-stats
  161. SELECT id, status, to_send, sent, started_at, updated_at
  162. FROM campaigns
  163. WHERE status=$1;
  164. -- name: next-campaigns
  165. -- Retreives campaigns that are running (or scheduled and the time's up) and need
  166. -- to be processed. It updates the to_send count and max_subscriber_id of the campaign,
  167. -- that is, the total number of subscribers to be processed across all lists of a campaign.
  168. -- Thus, it has a sideaffect.
  169. -- In addition, it finds the max_subscriber_id, the upper limit across all lists of
  170. -- a campaign. This is used to fetch and slice subscribers for the campaign in next-subscriber-campaigns.
  171. WITH camps AS (
  172. -- Get all running campaigns and their template bodies (if the template's deleted, the default template body instead)
  173. SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body
  174. FROM campaigns
  175. LEFT JOIN templates ON (templates.id = campaigns.template_id)
  176. WHERE (status='running' OR (status='scheduled' AND campaigns.send_at >= NOW()))
  177. AND NOT(campaigns.id = ANY($1::INT[]))
  178. ),
  179. counts AS (
  180. -- For each campaign above, get the total number of subscribers and the max_subscriber_id across all its lists.
  181. SELECT campaign_id, COUNT(subs.id) as to_send, COALESCE(MAX(subs.id), 0) as max_subscriber_id
  182. FROM subscribers subs, subscriber_lists sublists, campaign_lists camplists
  183. WHERE sublists.list_id = camplists.list_id AND
  184. subs.id = sublists.subscriber_id
  185. AND camplists.campaign_id = ANY(SELECT id FROM camps)
  186. GROUP BY camplists.campaign_id
  187. ),
  188. u AS (
  189. -- For each campaign above, update the to_send count.
  190. UPDATE campaigns AS ca
  191. SET to_send = co.to_send,
  192. max_subscriber_id = co.max_subscriber_id,
  193. started_at=(CASE WHEN ca.started_at IS NULL THEN NOW() ELSE ca.started_at END)
  194. FROM (SELECT * FROM counts) co
  195. WHERE ca.id = co.campaign_id
  196. )
  197. SELECT * FROM camps;
  198. -- name: next-campaign-subscribers
  199. -- Returns a batch of subscribers in a given campaign starting from the last checkpoint
  200. -- (last_subscriber_id). Every fetch updates the checkpoint and the sent count, which means
  201. -- every fetch returns a new batch of subscribers until all rows are exhausted.
  202. WITH camp AS (
  203. SELECT last_subscriber_id, max_subscriber_id
  204. FROM campaigns
  205. WHERE id=$1 AND status='running'
  206. ),
  207. subs AS (
  208. SELECT * FROM subscribers
  209. LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id AND subscriber_lists.status != 'unsubscribed')
  210. WHERE subscriber_lists.list_id=ANY(
  211. SELECT list_id FROM campaign_lists where campaign_id=$1 AND list_id IS NOT NULL
  212. )
  213. AND id > (SELECT last_subscriber_id FROM camp)
  214. AND id <= (SELECT max_subscriber_id FROM camp)
  215. ORDER BY id LIMIT $2
  216. ),
  217. u AS (
  218. UPDATE campaigns
  219. SET last_subscriber_id=(SELECT MAX(id) FROM subs),
  220. sent=sent + (SELECT COUNT(id) FROM subs),
  221. updated_at=NOW()
  222. WHERE (SELECT COUNT(id) FROM subs) > 0 AND id=$1
  223. )
  224. SELECT * FROM subs;
  225. -- name: get-one-campaign-subscriber
  226. SELECT * FROM subscribers
  227. LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id AND subscriber_lists.status != 'unsubscribed')
  228. WHERE subscriber_lists.list_id=ANY(
  229. SELECT list_id FROM campaign_lists where campaign_id=$1 AND list_id IS NOT NULL
  230. )
  231. LIMIT 1;
  232. -- name: update-campaign
  233. WITH camp AS (
  234. UPDATE campaigns SET
  235. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  236. subject=(CASE WHEN $3 != '' THEN $3 ELSE subject END),
  237. from_email=(CASE WHEN $4 != '' THEN $4 ELSE from_email END),
  238. body=(CASE WHEN $5 != '' THEN $5 ELSE body END),
  239. content_type=(CASE WHEN $6 != '' THEN $6::content_type ELSE content_type END),
  240. send_at=(CASE WHEN $7 != '' THEN $7::TIMESTAMP WITH TIME ZONE ELSE send_at END),
  241. tags=(CASE WHEN ARRAY_LENGTH($8::VARCHAR(100)[], 1) > 0 THEN $8 ELSE tags END),
  242. template_id=(CASE WHEN $9 != 0 THEN $9 ELSE template_id END),
  243. updated_at=NOW()
  244. WHERE id = $1 RETURNING id
  245. ),
  246. -- Reset the relationships
  247. d AS (
  248. DELETE FROM campaign_lists WHERE campaign_id = $1
  249. )
  250. INSERT INTO campaign_lists (campaign_id, list_id, list_name)
  251. (SELECT $1 as campaign_id, id, name FROM lists WHERE id=ANY($10::INT[]))
  252. ON CONFLICT (campaign_id, list_id) DO UPDATE SET list_name = EXCLUDED.list_name;
  253. -- name: update-campaign-counts
  254. UPDATE campaigns SET
  255. to_send=(CASE WHEN $2 != 0 THEN $2 ELSE to_send END),
  256. sent=(CASE WHEN $3 != 0 THEN $3 ELSE sent END),
  257. last_subscriber_id=(CASE WHEN $4 != 0 THEN $4 ELSE last_subscriber_id END),
  258. updated_at=NOW()
  259. WHERE id=$1;
  260. -- name: update-campaign-status
  261. UPDATE campaigns SET status=$2, updated_at=NOW() WHERE id = $1;
  262. -- name: delete-campaign
  263. DELETE FROM campaigns WHERE id=$1 AND (status = 'draft' OR status = 'scheduled');
  264. -- users
  265. -- name: get-users
  266. SELECT * FROM users WHERE $1 = 0 OR id = $1 OFFSET $2 LIMIT $3;
  267. -- name: create-user
  268. INSERT INTO users (email, name, password, type, status) VALUES($1, $2, $3, $4, $5) RETURNING id;
  269. -- name: update-user
  270. UPDATE users SET
  271. email=(CASE WHEN $2 != '' THEN $2 ELSE email END),
  272. name=(CASE WHEN $3 != '' THEN $3 ELSE name END),
  273. password=(CASE WHEN $4 != '' THEN $4 ELSE password END),
  274. type=(CASE WHEN $5 != '' THEN $5::user_type ELSE type END),
  275. status=(CASE WHEN $6 != '' THEN $6::user_status ELSE status END),
  276. updated_at=NOW()
  277. WHERE id = $1;
  278. -- name: delete-user
  279. -- Delete a user, except for the primordial super admin.
  280. DELETE FROM users WHERE $1 != 1 AND id=$1;
  281. -- templates
  282. -- name: get-templates
  283. -- Only if the second param ($2) is true, body is returned.
  284. SELECT id, name, (CASE WHEN $2 = false THEN body ELSE '' END) as body,
  285. is_default, created_at, updated_at
  286. FROM templates WHERE $1 = 0 OR id = $1
  287. ORDER BY created_at;
  288. -- name: create-template
  289. INSERT INTO templates (name, body) VALUES($1, $2) RETURNING id;
  290. -- name: update-template
  291. UPDATE templates SET
  292. name=(CASE WHEN $2 != '' THEN $2 ELSE name END),
  293. body=(CASE WHEN $3 != '' THEN $3 ELSE body END),
  294. updated_at=NOW()
  295. WHERE id = $1;
  296. -- name: set-default-template
  297. WITH u AS (
  298. UPDATE templates SET is_default=true WHERE id=$1 RETURNING id
  299. )
  300. UPDATE templates SET is_default=false WHERE id != $1;
  301. -- name: delete-template
  302. -- Delete a template as long as there's more than one.
  303. DELETE FROM templates WHERE id=$1 AND (SELECT COUNT(id) FROM templates) > 1 AND is_default = false;
  304. -- media
  305. -- name: insert-media
  306. INSERT INTO media (uuid, filename, thumb, width, height, created_at) VALUES($1, $2, $3, $4, $5, NOW());
  307. -- name: get-media
  308. SELECT * FROM media ORDER BY created_at DESC;
  309. -- name: delete-media
  310. DELETE FROM media WHERE id=$1 RETURNING filename;
  311. -- links
  312. -- name: create-link
  313. INSERT INTO links (uuid, url) VALUES($1, $2) ON CONFLICT (url) DO UPDATE SET url=EXCLUDED.url RETURNING uuid;
  314. -- name: register-link-click
  315. WITH link AS (
  316. SELECT url, links.id AS link_id, campaigns.id as campaign_id, subscribers.id AS subscriber_id FROM links
  317. LEFT JOIN campaigns ON (campaigns.uuid = $2)
  318. LEFT JOIN subscribers ON (subscribers.uuid = $3)
  319. WHERE links.uuid = $1
  320. )
  321. INSERT INTO link_clicks (campaign_id, subscriber_id, link_id)
  322. VALUES((SELECT campaign_id FROM link), (SELECT subscriber_id FROM link), (SELECT link_id FROM link))
  323. RETURNING (SELECT url FROM link);
  324. -- -- name: get-stats
  325. -- WITH lists AS (
  326. -- SELECT type, COUNT(id) AS num FROM lists GROUP BY type
  327. -- ),
  328. -- subs AS (
  329. -- SELECT status, COUNT(id) AS num FROM subscribers GROUP by status
  330. -- ),
  331. -- orphans AS (
  332. -- SELECT COUNT(id) FROM subscribers LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id)
  333. -- WHERE subscriber_lists.subscriber_id IS NULL
  334. -- ),
  335. -- camps AS (
  336. -- SELECT status, COUNT(id) AS num FROM campaigns GROUP by status
  337. -- )
  338. -- SELECT JSON_BUILD_OBJECT('lists', lists);
  339. -- row_to_json(t)
  340. -- from (
  341. -- select type, num from lists
  342. -- ) t,