Skip to content

Instantly share code, notes, and snippets.

@maxhawkins
Created May 23, 2021 14:16
Show Gist options
  • Save maxhawkins/6093f597a510b679d59b7f7b6bbb22e4 to your computer and use it in GitHub Desktop.
Save maxhawkins/6093f597a510b679d59b7f7b6bbb22e4 to your computer and use it in GitHub Desktop.
-- subscribers
DROP TABLE IF EXISTS subscribers;
CREATE TABLE subscribers (
id INTEGER PRIMARY KEY,
uuid TEXT NOT NULL UNIQUE,
email TEXT NOT NULL UNIQUE,
name TEXT NOT NULL,
attribs TEXT NOT NULL DEFAULT '{}' CHECK (json(attribs) IS NOT NULL),
status TEXT NOT NULL DEFAULT 'enabled' CHECK (status IN ('enabled', 'disabled', 'blocklisted')),
campaigns TEXT CHECK (json_array_length(campaigns) > 0),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP INDEX IF EXISTS idx_subs_email; CREATE UNIQUE INDEX idx_subs_email ON subscribers(LOWER(email));
DROP INDEX IF EXISTS idx_subs_status; CREATE INDEX idx_subs_status ON subscribers(status);
-- lists
DROP TABLE IF EXISTS lists;
CREATE TABLE lists (
id INTEGER PRIMARY KEY,
uuid TEXT NOT NULL UNIQUE,
name TEXT NOT NULL,
type TEXT NOT NULL CHECK (type IN ('public', 'private', 'temporary')),
optin TEXT NOT NULL DEFAULT 'single' CHECK (optin IN ('single', 'double')),
tags TEXT CHECK (json_array_length(tags) > 0),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP TABLE IF EXISTS subscriber_lists;
CREATE TABLE subscriber_lists (
subscriber_id INTEGER REFERENCES subscribers(id) ON DELETE CASCADE ON UPDATE CASCADE,
list_id INTEGER NULL REFERENCES lists(id) ON DELETE CASCADE ON UPDATE CASCADE,
status TEXT NOT NULL DEFAULT 'unconfirmed' CHECK (status IN ('unconfirmed', 'confirmed', 'unsubscribed')),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY(subscriber_id, list_id)
);
DROP INDEX IF EXISTS idx_sub_lists_sub_id; CREATE INDEX idx_sub_lists_sub_id ON subscriber_lists(subscriber_id);
DROP INDEX IF EXISTS idx_sub_lists_list_id; CREATE INDEX idx_sub_lists_list_id ON subscriber_lists(list_id);
DROP INDEX IF EXISTS idx_sub_lists_status; CREATE INDEX idx_sub_lists_status ON subscriber_lists(status);
-- templates
DROP TABLE IF EXISTS templates;
CREATE TABLE templates (
id INTEGER PRIMARY KEY,
name TEXT NOT NULL,
body TEXT NOT NULL,
is_default BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE UNIQUE INDEX idx_default_template ON templates (is_default) WHERE is_default = true;
-- campaigns
DROP TABLE IF EXISTS campaigns;
CREATE TABLE campaigns (
id INTEGER PRIMARY KEY,
uuid TEXT NOT NULL UNIQUE,
name TEXT NOT NULL,
subject TEXT NOT NULL,
from_email TEXT NOT NULL,
body TEXT NOT NULL,
altbody TEXT NULL,
content_type TEXT NOT NULL DEFAULT 'richtext' CHECK (content_type IN ('richtext', 'html', 'plain', 'markdown')),
send_at TIMESTAMP,
status TEXT NOT NULL DEFAULT 'draft' CHECK (status IN ('draft', 'running', 'scheduled', 'paused', 'cancelled', 'finished')),
tags TEXT CHECK (json_array_length(tags) > 0),
-- The subscription statuses of subscribers to which a campaign will be sent.
-- For opt-in campaigns, this will be 'unsubscribed'.
type TEXT DEFAULT 'regular' CHECK (type IN ('regular', 'optin')),
-- The ID of the messenger backend used to send this campaign.
messenger TEXT NOT NULL,
template_id INTEGER REFERENCES templates(id) ON DELETE SET DEFAULT DEFAULT 1,
-- Progress and stats.
to_send INT NOT NULL DEFAULT 0,
sent INT NOT NULL DEFAULT 0,
max_subscriber_id INT NOT NULL DEFAULT 0,
last_subscriber_id INT NOT NULL DEFAULT 0,
started_at TIMESTAMP,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP TABLE IF EXISTS campaign_lists;
CREATE TABLE campaign_lists (
campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
-- Lists may be deleted, so list_id is nullable
-- and a copy of the original list name is maintained here.
list_id INTEGER NULL REFERENCES lists(id) ON DELETE SET NULL ON UPDATE CASCADE,
list_name TEXT NOT NULL DEFAULT ''
);
CREATE UNIQUE INDEX idx_camp_lists_uniq ON campaign_lists (campaign_id, list_id);
DROP INDEX IF EXISTS idx_camp_lists_camp_id; CREATE INDEX idx_camp_lists_camp_id ON campaign_lists(campaign_id);
DROP INDEX IF EXISTS idx_camp_lists_list_id; CREATE INDEX idx_camp_lists_list_id ON campaign_lists(list_id);
DROP TABLE IF EXISTS campaign_views;
CREATE TABLE campaign_views (
campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
-- Subscribers may be deleted, but the view counts should remain.
subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP INDEX IF EXISTS idx_views_camp_id; CREATE INDEX idx_views_camp_id ON campaign_views(campaign_id);
DROP INDEX IF EXISTS idx_views_subscriber_id; CREATE INDEX idx_views_subscriber_id ON campaign_views(subscriber_id);
-- media
DROP TABLE IF EXISTS media;
CREATE TABLE media (
id INTEGER PRIMARY KEY,
uuid uuid NOT NULL UNIQUE,
provider TEXT NOT NULL DEFAULT '',
filename TEXT NOT NULL,
thumb TEXT NOT NULL,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- links
DROP TABLE IF EXISTS links;
CREATE TABLE links (
id TEXT PRIMARY KEY,
uuid TEXT NOT NULL UNIQUE,
url TEXT NOT NULL UNIQUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP TABLE IF EXISTS link_clicks;
CREATE TABLE link_clicks (
campaign_id INTEGER NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
link_id INTEGER NOT NULL REFERENCES links(id) ON DELETE CASCADE ON UPDATE CASCADE,
-- Subscribers may be deleted, but the link counts should remain.
subscriber_id INTEGER NULL REFERENCES subscribers(id) ON DELETE SET NULL ON UPDATE CASCADE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP INDEX IF EXISTS idx_clicks_camp_id; CREATE INDEX idx_clicks_camp_id ON link_clicks(campaign_id);
DROP INDEX IF EXISTS idx_clicks_link_id; CREATE INDEX idx_clicks_link_id ON link_clicks(link_id);
DROP INDEX IF EXISTS idx_clicks_sub_id; CREATE INDEX idx_clicks_sub_id ON link_clicks(subscriber_id);
-- settings
DROP TABLE IF EXISTS settings;
CREATE TABLE settings (
key TEXT NOT NULL UNIQUE,
value TEXT NOT NULL DEFAULT '{}' CHECK (json(value) IS NOT NULL),
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
DROP INDEX IF EXISTS idx_settings_key; CREATE INDEX idx_settings_key ON settings(key);
INSERT INTO settings (key, value) VALUES
('app.root_url', '"http://localhost:9000"'),
('app.favicon_url', '""'),
('app.from_email', '"listmonk <noreply@listmonk.yoursite.com>"'),
('app.logo_url', '"http://localhost:9000/public/static/logo.png"'),
('app.concurrency', '10'),
('app.message_rate', '10'),
('app.batch_size', '1000'),
('app.max_send_errors', '1000'),
('app.message_sliding_window', 'false'),
('app.message_sliding_window_duration', '"1h"'),
('app.message_sliding_window_rate', '10000'),
('app.enable_public_subscription_page', 'true'),
('app.check_updates', 'true'),
('app.notify_emails', '["admin1@mysite.com", "admin2@mysite.com"]'),
('app.lang', '"en"'),
('privacy.individual_tracking', 'false'),
('privacy.unsubscribe_header', 'true'),
('privacy.allow_blocklist', 'true'),
('privacy.allow_export', 'true'),
('privacy.allow_wipe', 'true'),
('privacy.exportable', '["profile", "subscriptions", "campaign_views", "link_clicks"]'),
('upload.provider', '"filesystem"'),
('upload.filesystem.upload_path', '"uploads"'),
('upload.filesystem.upload_uri', '"/uploads"'),
('upload.s3.aws_access_key_id', '""'),
('upload.s3.aws_secret_access_key', '""'),
('upload.s3.aws_default_region', '"ap-south-b"'),
('upload.s3.bucket', '""'),
('upload.s3.bucket_domain', '""'),
('upload.s3.bucket_path', '"/"'),
('upload.s3.bucket_type', '"public"'),
('upload.s3.expiry', '"14d"'),
('smtp',
'[{"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":[]},
{"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":[]}]'),
('messengers', '[]');
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment