schema.sql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237
  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. -- subscribers
  10. DROP TABLE IF EXISTS subscribers CASCADE;
  11. CREATE TABLE subscribers (
  12. id SERIAL PRIMARY KEY,
  13. uuid uuid NOT NULL UNIQUE,
  14. email TEXT NOT NULL UNIQUE,
  15. name TEXT NOT NULL,
  16. attribs JSONB NOT NULL DEFAULT '{}',
  17. status subscriber_status NOT NULL DEFAULT 'enabled',
  18. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  19. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  20. );
  21. DROP INDEX IF EXISTS idx_subs_email; CREATE UNIQUE INDEX idx_subs_email ON subscribers(LOWER(email));
  22. DROP INDEX IF EXISTS idx_subs_status; CREATE INDEX idx_subs_status ON subscribers(status);
  23. -- lists
  24. DROP TABLE IF EXISTS lists CASCADE;
  25. CREATE TABLE lists (
  26. id SERIAL PRIMARY KEY,
  27. uuid uuid NOT NULL UNIQUE,
  28. name TEXT NOT NULL,
  29. type list_type NOT NULL,
  30. optin list_optin NOT NULL DEFAULT 'single',
  31. tags VARCHAR(100)[],
  32. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  33. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  34. );
  35. DROP TABLE IF EXISTS subscriber_lists CASCADE;
  36. CREATE TABLE subscriber_lists (
  37. subscriber_id INTEGER REFERENCES subscribers(id) ON DELETE CASCADE ON UPDATE CASCADE,
  38. list_id INTEGER NULL REFERENCES lists(id) ON DELETE CASCADE ON UPDATE CASCADE,
  39. status subscription_status NOT NULL DEFAULT 'unconfirmed',
  40. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  41. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  42. PRIMARY KEY(subscriber_id, list_id)
  43. );
  44. DROP INDEX IF EXISTS idx_sub_lists_sub_id; CREATE INDEX idx_sub_lists_sub_id ON subscriber_lists(subscriber_id);
  45. DROP INDEX IF EXISTS idx_sub_lists_list_id; CREATE INDEX idx_sub_lists_list_id ON subscriber_lists(list_id);
  46. DROP INDEX IF EXISTS idx_sub_lists_status; CREATE INDEX idx_sub_lists_status ON subscriber_lists(status);
  47. -- templates
  48. DROP TABLE IF EXISTS templates CASCADE;
  49. CREATE TABLE templates (
  50. id SERIAL PRIMARY KEY,
  51. name TEXT NOT NULL,
  52. body TEXT NOT NULL,
  53. is_default BOOLEAN NOT NULL DEFAULT false,
  54. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  55. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  56. );
  57. CREATE UNIQUE INDEX ON templates (is_default) WHERE is_default = true;
  58. -- campaigns
  59. DROP TABLE IF EXISTS campaigns CASCADE;
  60. CREATE TABLE campaigns (
  61. id SERIAL PRIMARY KEY,
  62. uuid uuid NOT NULL UNIQUE,
  63. name TEXT NOT NULL,
  64. subject TEXT NOT NULL,
  65. from_email TEXT NOT NULL,
  66. body TEXT NOT NULL,
  67. altbody TEXT NULL,
  68. content_type content_type NOT NULL DEFAULT 'richtext',
  69. send_at TIMESTAMP WITH TIME ZONE,
  70. status campaign_status NOT NULL DEFAULT 'draft',
  71. tags VARCHAR(100)[],
  72. -- The subscription statuses of subscribers to which a campaign will be sent.
  73. -- For opt-in campaigns, this will be 'unsubscribed'.
  74. type campaign_type DEFAULT 'regular',
  75. -- The ID of the messenger backend used to send this campaign.
  76. messenger TEXT NOT NULL,
  77. template_id INTEGER REFERENCES templates(id) ON DELETE SET DEFAULT DEFAULT 1,
  78. -- Progress and stats.
  79. to_send INT NOT NULL DEFAULT 0,
  80. sent INT NOT NULL DEFAULT 0,
  81. max_subscriber_id INT NOT NULL DEFAULT 0,
  82. last_subscriber_id INT NOT NULL DEFAULT 0,
  83. started_at TIMESTAMP WITH TIME ZONE,
  84. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
  85. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  86. );
  87. DROP TABLE IF EXISTS campaign_lists CASCADE;
  88. CREATE TABLE campaign_lists (
  89. id BIGSERIAL PRIMARY KEY,
  90. campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  91. -- Lists may be deleted, so list_id is nullable
  92. -- and a copy of the original list name is maintained here.
  93. list_id INTEGER NULL REFERENCES lists(id) ON DELETE SET NULL ON UPDATE CASCADE,
  94. list_name TEXT NOT NULL DEFAULT ''
  95. );
  96. CREATE UNIQUE INDEX ON campaign_lists (campaign_id, list_id);
  97. DROP INDEX IF EXISTS idx_camp_lists_camp_id; CREATE INDEX idx_camp_lists_camp_id ON campaign_lists(campaign_id);
  98. DROP INDEX IF EXISTS idx_camp_lists_list_id; CREATE INDEX idx_camp_lists_list_id ON campaign_lists(list_id);
  99. DROP TABLE IF EXISTS campaign_views CASCADE;
  100. CREATE TABLE campaign_views (
  101. id BIGSERIAL PRIMARY KEY,
  102. campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  103. -- Subscribers may be deleted, but the view counts should remain.
  104. subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
  105. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  106. );
  107. DROP INDEX IF EXISTS idx_views_camp_id; CREATE INDEX idx_views_camp_id ON campaign_views(campaign_id);
  108. DROP INDEX IF EXISTS idx_views_subscriber_id; CREATE INDEX idx_views_subscriber_id ON campaign_views(subscriber_id);
  109. DROP INDEX IF EXISTS idx_views_date; CREATE INDEX idx_views_date ON campaign_views((TIMEZONE('UTC', created_at)::DATE));
  110. -- media
  111. DROP TABLE IF EXISTS media CASCADE;
  112. CREATE TABLE media (
  113. id SERIAL PRIMARY KEY,
  114. uuid uuid NOT NULL UNIQUE,
  115. provider TEXT NOT NULL DEFAULT '',
  116. filename TEXT NOT NULL,
  117. thumb TEXT NOT NULL,
  118. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  119. );
  120. -- links
  121. DROP TABLE IF EXISTS links CASCADE;
  122. CREATE TABLE links (
  123. id SERIAL PRIMARY KEY,
  124. uuid uuid NOT NULL UNIQUE,
  125. url TEXT NOT NULL UNIQUE,
  126. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  127. );
  128. DROP TABLE IF EXISTS link_clicks CASCADE;
  129. CREATE TABLE link_clicks (
  130. id BIGSERIAL PRIMARY KEY,
  131. campaign_id INTEGER NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
  132. link_id INTEGER NOT NULL REFERENCES links(id) ON DELETE CASCADE ON UPDATE CASCADE,
  133. -- Subscribers may be deleted, but the link counts should remain.
  134. subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
  135. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  136. );
  137. DROP INDEX IF EXISTS idx_clicks_camp_id; CREATE INDEX idx_clicks_camp_id ON link_clicks(campaign_id);
  138. DROP INDEX IF EXISTS idx_clicks_link_id; CREATE INDEX idx_clicks_link_id ON link_clicks(link_id);
  139. DROP INDEX IF EXISTS idx_clicks_sub_id; CREATE INDEX idx_clicks_sub_id ON link_clicks(subscriber_id);
  140. DROP INDEX IF EXISTS idx_clicks_date; CREATE INDEX idx_clicks_date ON link_clicks((TIMEZONE('UTC', created_at)::DATE));
  141. -- settings
  142. DROP TABLE IF EXISTS settings CASCADE;
  143. CREATE TABLE settings (
  144. key TEXT NOT NULL UNIQUE,
  145. value JSONB NOT NULL DEFAULT '{}',
  146. updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  147. );
  148. DROP INDEX IF EXISTS idx_settings_key; CREATE INDEX idx_settings_key ON settings(key);
  149. INSERT INTO settings (key, value) VALUES
  150. ('app.root_url', '"http://localhost:9000"'),
  151. ('app.favicon_url', '""'),
  152. ('app.from_email', '"listmonk <noreply@listmonk.yoursite.com>"'),
  153. ('app.logo_url', '"http://localhost:9000/public/static/logo.png"'),
  154. ('app.concurrency', '10'),
  155. ('app.message_rate', '10'),
  156. ('app.batch_size', '1000'),
  157. ('app.max_send_errors', '1000'),
  158. ('app.message_sliding_window', 'false'),
  159. ('app.message_sliding_window_duration', '"1h"'),
  160. ('app.message_sliding_window_rate', '10000'),
  161. ('app.enable_public_subscription_page', 'true'),
  162. ('app.send_optin_confirmation', 'true'),
  163. ('app.check_updates', 'true'),
  164. ('app.notify_emails', '["admin1@mysite.com", "admin2@mysite.com"]'),
  165. ('app.lang', '"en"'),
  166. ('privacy.individual_tracking', 'false'),
  167. ('privacy.unsubscribe_header', 'true'),
  168. ('privacy.allow_blocklist', 'true'),
  169. ('privacy.allow_export', 'true'),
  170. ('privacy.allow_wipe', 'true'),
  171. ('privacy.exportable', '["profile", "subscriptions", "campaign_views", "link_clicks"]'),
  172. ('privacy.domain_blocklist', '[]'),
  173. ('upload.provider', '"filesystem"'),
  174. ('upload.filesystem.upload_path', '"uploads"'),
  175. ('upload.filesystem.upload_uri', '"/uploads"'),
  176. ('upload.s3.url', '"https://ap-south-1.s3.amazonaws.com"'),
  177. ('upload.s3.aws_access_key_id', '""'),
  178. ('upload.s3.aws_secret_access_key', '""'),
  179. ('upload.s3.aws_default_region', '"ap-south-1"'),
  180. ('upload.s3.bucket', '""'),
  181. ('upload.s3.bucket_domain', '""'),
  182. ('upload.s3.bucket_path', '"/"'),
  183. ('upload.s3.bucket_type', '"public"'),
  184. ('upload.s3.expiry', '"14d"'),
  185. ('smtp',
  186. '[{"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_enabled":true,"tls_skip_verify":false,"email_headers":[]},
  187. {"enabled":false, "host":"smtp2.yoursite.com","port":587,"auth_protocol":"plain","username":"username","password":"password","hello_hostname":"","max_conns":10,"idle_timeout":"15s","wait_timeout":"5s","max_msg_retries":2,"tls_enabled":false,"tls_skip_verify":false,"email_headers":[]}]'),
  188. ('messengers', '[]'),
  189. ('bounce.enabled', 'false'),
  190. ('bounce.webhooks_enabled', 'false'),
  191. ('bounce.count', '2'),
  192. ('bounce.action', '"blocklist"'),
  193. ('bounce.ses_enabled', 'false'),
  194. ('bounce.sendgrid_enabled', 'false'),
  195. ('bounce.sendgrid_key', '""'),
  196. ('bounce.mailboxes',
  197. '[{"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}]');
  198. -- bounces
  199. DROP TABLE IF EXISTS bounces CASCADE;
  200. CREATE TABLE bounces (
  201. id SERIAL PRIMARY KEY,
  202. subscriber_id INTEGER NOT NULL REFERENCES subscribers(id) ON DELETE CASCADE ON UPDATE CASCADE,
  203. campaign_id INTEGER NULL REFERENCES campaigns(id) ON DELETE SET NULL ON UPDATE CASCADE,
  204. type bounce_type NOT NULL DEFAULT 'hard',
  205. source TEXT NOT NULL DEFAULT '',
  206. meta JSONB NOT NULL DEFAULT '{}',
  207. created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
  208. );
  209. DROP INDEX IF EXISTS idx_bounces_sub_id; CREATE INDEX idx_bounces_sub_id ON bounces(subscriber_id);
  210. DROP INDEX IF EXISTS idx_bounces_camp_id; CREATE INDEX idx_bounces_camp_id ON bounces(campaign_id);
  211. DROP INDEX IF EXISTS idx_bounces_source; CREATE INDEX idx_bounces_source ON bounces(source);
  212. DROP INDEX IF EXISTS idx_bounces_date; CREATE INDEX idx_bounces_date ON bounces((TIMEZONE('UTC', created_at)::DATE));