schema.sql 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280
  1. DROP TYPE IF EXISTS list_type CASCADE; CREATE TYPE list_type AS ENUM ('public', 'private', 'temporary');
  2. DROP TYPE IF EXISTS list_optin CASCADE; CREATE TYPE list_optin AS ENUM ('single', 'double');
  3. DROP TYPE IF EXISTS subscriber_status CASCADE; CREATE TYPE subscriber_status AS ENUM ('enabled', 'disabled', 'blocklisted');
  4. DROP TYPE IF EXISTS subscription_status CASCADE; CREATE TYPE subscription_status AS ENUM ('unconfirmed', 'confirmed', 'unsubscribed');
  5. DROP TYPE IF EXISTS campaign_status CASCADE; CREATE TYPE campaign_status AS ENUM ('draft', 'running', 'scheduled', 'paused', 'cancelled', 'finished');
  6. DROP TYPE IF EXISTS campaign_type CASCADE; CREATE TYPE campaign_type AS ENUM ('regular', 'optin');
  7. DROP TYPE IF EXISTS content_type CASCADE; CREATE TYPE content_type AS ENUM ('richtext', 'html', 'plain', 'markdown');
  8. DROP TYPE IF EXISTS bounce_type CASCADE; CREATE TYPE bounce_type AS ENUM ('soft', 'hard', 'complaint');
  9. DROP TYPE IF EXISTS template_type CASCADE; CREATE TYPE template_type AS ENUM ('campaign', 'tx');
  10. -- subscribers
  11. DROP TABLE IF EXISTS subscribers CASCADE;
  12. CREATE TABLE subscribers (
  13. id SERIAL PRIMARY KEY,
  14. uuid uuid NOT NULL UNIQUE,
  15. email TEXT NOT NULL UNIQUE,
  16. name TEXT NOT NULL,
  17. attribs JSONB NOT NULL DEFAULT '{}',
  18. status subscriber_status NOT NULL DEFAULT 'enabled',
  19. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  20. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  21. );
  22. DROP INDEX IF EXISTS idx_subs_email; CREATE UNIQUE INDEX idx_subs_email ON subscribers(LOWER(email));
  23. DROP INDEX IF EXISTS idx_subs_status; CREATE INDEX idx_subs_status ON subscribers(status);
  24. -- lists
  25. DROP TABLE IF EXISTS lists CASCADE;
  26. CREATE TABLE lists (
  27. id SERIAL PRIMARY KEY,
  28. uuid uuid NOT NULL UNIQUE,
  29. name TEXT NOT NULL,
  30. type list_type NOT NULL,
  31. optin list_optin NOT NULL DEFAULT 'single',
  32. tags VARCHAR(100)[],
  33. description TEXT NOT NULL DEFAULT '',
  34. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  35. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  36. );
  37. DROP TABLE IF EXISTS subscriber_lists CASCADE;
  38. CREATE TABLE subscriber_lists (
  39. subscriber_id INTEGER REFERENCES subscribers(id) ON DELETE CASCADE ON UPDATE CASCADE,
  40. list_id INTEGER NULL REFERENCES lists(id) ON DELETE CASCADE ON UPDATE CASCADE,
  41. meta JSONB NOT NULL DEFAULT '{}',
  42. status subscription_status NOT NULL DEFAULT 'unconfirmed',
  43. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  44. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  45. PRIMARY KEY(subscriber_id, list_id)
  46. );
  47. DROP INDEX IF EXISTS idx_sub_lists_sub_id; CREATE INDEX idx_sub_lists_sub_id ON subscriber_lists(subscriber_id);
  48. DROP INDEX IF EXISTS idx_sub_lists_list_id; CREATE INDEX idx_sub_lists_list_id ON subscriber_lists(list_id);
  49. DROP INDEX IF EXISTS idx_sub_lists_status; CREATE INDEX idx_sub_lists_status ON subscriber_lists(status);
  50. -- templates
  51. DROP TABLE IF EXISTS templates CASCADE;
  52. CREATE TABLE templates (
  53. id SERIAL PRIMARY KEY,
  54. name TEXT NOT NULL,
  55. type template_type NOT NULL DEFAULT 'campaign',
  56. subject TEXT NOT NULL,
  57. body TEXT NOT NULL,
  58. is_default BOOLEAN NOT NULL DEFAULT false,
  59. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  60. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  61. );
  62. CREATE UNIQUE INDEX ON templates (is_default) WHERE is_default = true;
  63. -- campaigns
  64. DROP TABLE IF EXISTS campaigns CASCADE;
  65. CREATE TABLE campaigns (
  66. id SERIAL PRIMARY KEY,
  67. uuid uuid NOT NULL UNIQUE,
  68. name TEXT NOT NULL,
  69. subject TEXT NOT NULL,
  70. from_email TEXT NOT NULL,
  71. body TEXT NOT NULL,
  72. altbody TEXT NULL,
  73. content_type content_type NOT NULL DEFAULT 'richtext',
  74. send_at TIMESTAMP WITH TIME ZONE,
  75. headers JSONB NOT NULL DEFAULT '[]',
  76. status campaign_status NOT NULL DEFAULT 'draft',
  77. tags VARCHAR(100)[],
  78. -- The subscription statuses of subscribers to which a campaign will be sent.
  79. -- For opt-in campaigns, this will be 'unsubscribed'.
  80. type campaign_type DEFAULT 'regular',
  81. -- The ID of the messenger backend used to send this campaign.
  82. messenger TEXT NOT NULL,
  83. template_id INTEGER REFERENCES templates(id) ON DELETE SET DEFAULT DEFAULT 1,
  84. -- Progress and stats.
  85. to_send INT NOT NULL DEFAULT 0,
  86. sent INT NOT NULL DEFAULT 0,
  87. max_subscriber_id INT NOT NULL DEFAULT 0,
  88. last_subscriber_id INT NOT NULL DEFAULT 0,
  89. -- Publishing.
  90. archive BOOLEAN NOT NULL DEFAULT false,
  91. archive_template_id INTEGER REFERENCES templates(id) ON DELETE SET DEFAULT DEFAULT 1,
  92. archive_meta JSONB NOT NULL DEFAULT '{}',
  93. started_at TIMESTAMP WITH TIME ZONE,
  94. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  95. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  96. );
  97. DROP TABLE IF EXISTS campaign_lists CASCADE;
  98. CREATE TABLE campaign_lists (
  99. id BIGSERIAL PRIMARY KEY,
  100. campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  101. -- Lists may be deleted, so list_id is nullable
  102. -- and a copy of the original list name is maintained here.
  103. list_id INTEGER NULL REFERENCES lists(id) ON DELETE SET NULL ON UPDATE CASCADE,
  104. list_name TEXT NOT NULL DEFAULT ''
  105. );
  106. CREATE UNIQUE INDEX ON campaign_lists (campaign_id, list_id);
  107. DROP INDEX IF EXISTS idx_camp_lists_camp_id; CREATE INDEX idx_camp_lists_camp_id ON campaign_lists(campaign_id);
  108. DROP INDEX IF EXISTS idx_camp_lists_list_id; CREATE INDEX idx_camp_lists_list_id ON campaign_lists(list_id);
  109. DROP TABLE IF EXISTS campaign_views CASCADE;
  110. CREATE TABLE campaign_views (
  111. id BIGSERIAL PRIMARY KEY,
  112. campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  113. -- Subscribers may be deleted, but the view counts should remain.
  114. subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
  115. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  116. );
  117. DROP INDEX IF EXISTS idx_views_camp_id; CREATE INDEX idx_views_camp_id ON campaign_views(campaign_id);
  118. DROP INDEX IF EXISTS idx_views_subscriber_id; CREATE INDEX idx_views_subscriber_id ON campaign_views(subscriber_id);
  119. DROP INDEX IF EXISTS idx_views_date; CREATE INDEX idx_views_date ON campaign_views((TIMEZONE('UTC', created_at)::DATE));
  120. -- media
  121. DROP TABLE IF EXISTS media CASCADE;
  122. CREATE TABLE media (
  123. id SERIAL PRIMARY KEY,
  124. uuid uuid NOT NULL UNIQUE,
  125. provider TEXT NOT NULL DEFAULT '',
  126. filename TEXT NOT NULL,
  127. content_type TEXT NOT NULL DEFAULT 'application/octet-stream',
  128. thumb TEXT NOT NULL,
  129. meta JSONB NOT NULL DEFAULT '{}',
  130. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  131. );
  132. -- campaign_media
  133. DROP TABLE IF EXISTS campaign_media CASCADE;
  134. CREATE TABLE campaign_media (
  135. campaign_id INTEGER REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  136. -- Media items may be deleted, so media_id is nullable
  137. -- and a copy of the original name is maintained here.
  138. media_id INTEGER NULL REFERENCES media(id) ON DELETE SET NULL ON UPDATE CASCADE,
  139. filename TEXT NOT NULL DEFAULT ''
  140. );
  141. DROP INDEX IF EXISTS idx_camp_media_id; CREATE UNIQUE INDEX idx_camp_media_id ON campaign_media (campaign_id, media_id);
  142. DROP INDEX IF EXISTS idx_camp_media_camp_id; CREATE INDEX idx_camp_media_camp_id ON campaign_media(campaign_id);
  143. -- links
  144. DROP TABLE IF EXISTS links CASCADE;
  145. CREATE TABLE links (
  146. id SERIAL PRIMARY KEY,
  147. uuid uuid NOT NULL UNIQUE,
  148. url TEXT NOT NULL UNIQUE,
  149. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  150. );
  151. DROP TABLE IF EXISTS link_clicks CASCADE;
  152. CREATE TABLE link_clicks (
  153. id BIGSERIAL PRIMARY KEY,
  154. campaign_id INTEGER NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  155. link_id INTEGER NOT NULL REFERENCES links(id) ON DELETE CASCADE ON UPDATE CASCADE,
  156. -- Subscribers may be deleted, but the link counts should remain.
  157. subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
  158. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  159. );
  160. DROP INDEX IF EXISTS idx_clicks_camp_id; CREATE INDEX idx_clicks_camp_id ON link_clicks(campaign_id);
  161. DROP INDEX IF EXISTS idx_clicks_link_id; CREATE INDEX idx_clicks_link_id ON link_clicks(link_id);
  162. DROP INDEX IF EXISTS idx_clicks_sub_id; CREATE INDEX idx_clicks_sub_id ON link_clicks(subscriber_id);
  163. DROP INDEX IF EXISTS idx_clicks_date; CREATE INDEX idx_clicks_date ON link_clicks((TIMEZONE('UTC', created_at)::DATE));
  164. -- settings
  165. DROP TABLE IF EXISTS settings CASCADE;
  166. CREATE TABLE settings (
  167. key TEXT NOT NULL UNIQUE,
  168. value JSONB NOT NULL DEFAULT '{}',
  169. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  170. );
  171. DROP INDEX IF EXISTS idx_settings_key; CREATE INDEX idx_settings_key ON settings(key);
  172. INSERT INTO settings (key, value) VALUES
  173. ('app.site_name', '"Mailing list"'),
  174. ('app.root_url', '"http://localhost:9000"'),
  175. ('app.favicon_url', '""'),
  176. ('app.from_email', '"listmonk <noreply@listmonk.yoursite.com>"'),
  177. ('app.logo_url', '""'),
  178. ('app.concurrency', '10'),
  179. ('app.message_rate', '10'),
  180. ('app.batch_size', '1000'),
  181. ('app.max_send_errors', '1000'),
  182. ('app.message_sliding_window', 'false'),
  183. ('app.message_sliding_window_duration', '"1h"'),
  184. ('app.message_sliding_window_rate', '10000'),
  185. ('app.enable_public_archive', 'true'),
  186. ('app.enable_public_subscription_page', 'true'),
  187. ('app.enable_public_archive_rss_content', 'true'),
  188. ('app.send_optin_confirmation', 'true'),
  189. ('app.check_updates', 'true'),
  190. ('app.notify_emails', '["admin1@mysite.com", "admin2@mysite.com"]'),
  191. ('app.lang', '"en"'),
  192. ('privacy.individual_tracking', 'false'),
  193. ('privacy.unsubscribe_header', 'true'),
  194. ('privacy.allow_blocklist', 'true'),
  195. ('privacy.allow_export', 'true'),
  196. ('privacy.allow_wipe', 'true'),
  197. ('privacy.allow_preferences', 'true'),
  198. ('privacy.exportable', '["profile", "subscriptions", "campaign_views", "link_clicks"]'),
  199. ('privacy.domain_blocklist', '[]'),
  200. ('privacy.record_optin_ip', 'false'),
  201. ('security.enable_captcha', 'false'),
  202. ('security.captcha_key', '""'),
  203. ('security.captcha_secret', '""'),
  204. ('upload.provider', '"filesystem"'),
  205. ('upload.max_file_size', '5000'),
  206. ('upload.extensions', '["jpg","jpeg","png","gif","svg","*"]'),
  207. ('upload.filesystem.upload_path', '"uploads"'),
  208. ('upload.filesystem.upload_uri', '"/uploads"'),
  209. ('upload.s3.url', '"https://ap-south-1.s3.amazonaws.com"'),
  210. ('upload.s3.public_url', '""'),
  211. ('upload.s3.aws_access_key_id', '""'),
  212. ('upload.s3.aws_secret_access_key', '""'),
  213. ('upload.s3.aws_default_region', '"ap-south-1"'),
  214. ('upload.s3.bucket', '""'),
  215. ('upload.s3.bucket_domain', '""'),
  216. ('upload.s3.bucket_path', '"/"'),
  217. ('upload.s3.bucket_type', '"public"'),
  218. ('upload.s3.expiry', '"167h"'),
  219. ('smtp',
  220. '[{"enabled":true, "host":"smtp.yoursite.com","port":25,"auth_protocol":"cram","username":"username","password":"password","hello_hostname":"","max_conns":10,"idle_timeout":"15s","wait_timeout":"5s","max_msg_retries":2,"tls_type":"STARTTLS","tls_skip_verify":false,"email_headers":[]},
  221. {"enabled":false, "host":"smtp.gmail.com","port":465,"auth_protocol":"login","username":"username@gmail.com","password":"password","hello_hostname":"","max_conns":10,"idle_timeout":"15s","wait_timeout":"5s","max_msg_retries":2,"tls_type":"TLS","tls_skip_verify":false,"email_headers":[]}]'),
  222. ('messengers', '[]'),
  223. ('bounce.enabled', 'false'),
  224. ('bounce.webhooks_enabled', 'false'),
  225. ('bounce.actions', '{"soft": {"count": 2, "action": "none"}, "hard": {"count": 2, "action": "blocklist"}, "complaint" : {"count": 2, "action": "delete"}}'),
  226. ('bounce.ses_enabled', 'false'),
  227. ('bounce.sendgrid_enabled', 'false'),
  228. ('bounce.sendgrid_key', '""'),
  229. ('bounce.postmark', '{"enabled": false, "username": "", "password": ""}'),
  230. ('bounce.mailboxes',
  231. '[{"enabled":false, "type": "pop", "host":"pop.yoursite.com","port":995,"auth_protocol":"userpass","username":"username","password":"password","return_path": "bounce@listmonk.yoursite.com","scan_interval":"15m","tls_enabled":true,"tls_skip_verify":false}]'),
  232. ('appearance.admin.custom_css', '""'),
  233. ('appearance.admin.custom_js', '""'),
  234. ('appearance.public.custom_css', '""'),
  235. ('appearance.public.custom_js', '""');
  236. -- bounces
  237. DROP TABLE IF EXISTS bounces CASCADE;
  238. CREATE TABLE bounces (
  239. id SERIAL PRIMARY KEY,
  240. subscriber_id INTEGER NOT NULL REFERENCES subscribers(id) ON DELETE CASCADE ON UPDATE CASCADE,
  241. campaign_id INTEGER NULL REFERENCES campaigns(id) ON DELETE SET NULL ON UPDATE CASCADE,
  242. type bounce_type NOT NULL DEFAULT 'hard',
  243. source TEXT NOT NULL DEFAULT '',
  244. meta JSONB NOT NULL DEFAULT '{}',
  245. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  246. );
  247. DROP INDEX IF EXISTS idx_bounces_sub_id; CREATE INDEX idx_bounces_sub_id ON bounces(subscriber_id);
  248. DROP INDEX IF EXISTS idx_bounces_camp_id; CREATE INDEX idx_bounces_camp_id ON bounces(campaign_id);
  249. DROP INDEX IF EXISTS idx_bounces_source; CREATE INDEX idx_bounces_source ON bounces(source);
  250. DROP INDEX IF EXISTS idx_bounces_date; CREATE INDEX idx_bounces_date ON bounces((TIMEZONE('UTC', created_at)::DATE));