Add missing id (pkey) to analytics tables for faster queries

This commit is contained in:
Kailash Nadh 2021-09-17 19:55:38 +05:30
parent 3d0031b207
commit 9302dfbd56
3 changed files with 27 additions and 7 deletions

View file

@ -39,7 +39,24 @@ func V2_0_0(db *sqlx.DB, fs stuffbin.FileSystem, ko *koanf.Koanf) error {
return err
}
if _, err := db.Exec(`ALTER TABLE subscribers DROP COLUMN IF EXISTS campaigns; `); err != nil {
if _, err := db.Exec(`ALTER TABLE subscribers DROP COLUMN IF EXISTS campaigns`); err != nil {
return err
}
if _, err := db.Exec(`
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_class WHERE relname = 'campaign_views_pkey') THEN
ALTER TABLE campaign_views ADD COLUMN IF NOT EXISTS id BIGSERIAL PRIMARY KEY;
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_class WHERE relname = 'link_clicks_pkey') THEN
ALTER TABLE link_clicks ADD COLUMN IF NOT EXISTS id BIGSERIAL PRIMARY KEY;
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_class WHERE relname = 'campaign_lists_pkey') THEN
ALTER TABLE campaign_lists ADD COLUMN IF NOT EXISTS id BIGSERIAL PRIMARY KEY;
END IF;
END$$;
`); err != nil {
return err
}

View file

@ -208,13 +208,13 @@ views AS (
SELECT subject as campaign, COUNT(subscriber_id) as views FROM campaign_views
LEFT JOIN campaigns ON (campaigns.id = campaign_views.campaign_id)
WHERE subscriber_id = (SELECT id FROM prof)
GROUP BY campaigns.id ORDER BY id
GROUP BY campaigns.id ORDER BY campaigns.id
),
clicks AS (
SELECT url, COUNT(subscriber_id) as clicks FROM link_clicks
LEFT JOIN links ON (links.id = link_clicks.link_id)
WHERE subscriber_id = (SELECT id FROM prof)
GROUP BY links.id ORDER BY id
GROUP BY links.id ORDER BY links.id
)
SELECT (SELECT email FROM prof) as email,
COALESCE((SELECT JSON_AGG(t) FROM prof t), '{}') AS profile,
@ -369,9 +369,9 @@ DELETE FROM lists WHERE id = ALL($1);
-- This creates the campaign and inserts campaign_lists relationships.
WITH campLists AS (
-- Get the list_ids and their optin statuses for the campaigns found in the previous step.
SELECT id AS list_id, campaign_id, optin FROM lists
SELECT lists.id AS list_id, campaign_id, optin FROM lists
INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
WHERE id=ANY($13::INT[])
WHERE lists.id = ANY($13::INT[])
),
tpl AS (
-- If there's no template_id given, use the defualt template.
@ -504,7 +504,7 @@ WITH camps AS (
),
campLists AS (
-- Get the list_ids and their optin statuses for the campaigns found in the previous step.
SELECT id AS list_id, campaign_id, optin FROM lists
SELECT lists.id AS list_id, campaign_id, optin FROM lists
INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
WHERE campaign_lists.campaign_id = ANY(SELECT id FROM camps)
),
@ -591,7 +591,7 @@ WITH camps AS (
WHERE id=$1 AND status='running'
),
campLists AS (
SELECT id AS list_id, optin FROM lists
SELECT lists.id AS list_id, optin FROM lists
INNER JOIN campaign_lists ON (campaign_lists.list_id = lists.id)
WHERE campaign_lists.campaign_id = $1
),

View file

@ -102,6 +102,7 @@ CREATE TABLE campaigns (
DROP TABLE IF EXISTS campaign_lists CASCADE;
CREATE TABLE campaign_lists (
id BIGSERIAL PRIMARY KEY,
campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
-- Lists may be deleted, so list_id is nullable
@ -115,6 +116,7 @@ DROP INDEX IF EXISTS idx_camp_lists_list_id; CREATE INDEX idx_camp_lists_list_id
DROP TABLE IF EXISTS campaign_views CASCADE;
CREATE TABLE campaign_views (
id BIGSERIAL PRIMARY KEY,
campaign_id INTEGER NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE ON UPDATE CASCADE,
-- Subscribers may be deleted, but the view counts should remain.
@ -146,6 +148,7 @@ CREATE TABLE links (
DROP TABLE IF EXISTS link_clicks CASCADE;
CREATE TABLE link_clicks (
id BIGSERIAL PRIMARY KEY,
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,