Optimize campaign and subscriber queries

- Simplify campaigns querying to separate statistics gather into
  a separate query for lazy loading.
- Simplify subscribers query to separate list fetching into
  a separate query for lazy loading.
This commit is contained in:
Kailash Nadh 2019-04-01 17:07:24 +05:30
parent 93c952082c
commit cfec13c589
5 changed files with 124 additions and 68 deletions

View file

@ -43,7 +43,7 @@ type campaignStats struct {
} }
type campsWrap struct { type campsWrap struct {
Results []models.Campaign `json:"results"` Results models.Campaigns `json:"results"`
Query string `json:"query"` Query string `json:"query"`
Total int `json:"total"` Total int `json:"total"`
@ -100,6 +100,12 @@ func handleGetCampaigns(c echo.Context) error {
} }
} }
// Lazy load stats.
if err := out.Results.LoadStats(app.Queries.GetCampaignStats); err != nil {
return echo.NewHTTPError(http.StatusInternalServerError,
fmt.Sprintf("Error fetching campaign stats: %v", pqErrMsg(err)))
}
if single { if single {
return c.JSON(http.StatusOK, okResp{out.Results[0]}) return c.JSON(http.StatusOK, okResp{out.Results[0]})
} }
@ -396,7 +402,7 @@ func handleGetRunningCampaignStats(c echo.Context) error {
out []campaignStats out []campaignStats
) )
if err := app.Queries.GetCampaignStats.Select(&out, models.CampaignStatusRunning); err != nil { if err := app.Queries.GetCampaignStatus.Select(&out, models.CampaignStatusRunning); err != nil {
if err == sql.ErrNoRows { if err == sql.ErrNoRows {
return c.JSON(http.StatusOK, okResp{[]struct{}{}}) return c.JSON(http.StatusOK, okResp{[]struct{}{}})
} }

View file

@ -159,9 +159,9 @@ class Campaigns extends React.PureComponent {
const out = [] const out = []
lists.forEach(l => { lists.forEach(l => {
out.push( out.push(
<span className="name" key={`name-${l.id}`}> <Tag className="name" key={`name-${l.id}`}>
<Link to={`/subscribers/lists/${l.id}`}>{l.name}</Link> <Link to={`/subscribers/lists/${l.id}`}>{l.name}</Link>
</span> </Tag>
) )
}) })

View file

@ -3,6 +3,7 @@ package models
import ( import (
"database/sql/driver" "database/sql/driver"
"encoding/json" "encoding/json"
"errors"
"fmt" "fmt"
"html/template" "html/template"
"regexp" "regexp"
@ -90,12 +91,16 @@ type Subscriber struct {
Attribs SubscriberAttribs `db:"attribs" json:"attribs"` Attribs SubscriberAttribs `db:"attribs" json:"attribs"`
Status string `db:"status" json:"status"` Status string `db:"status" json:"status"`
CampaignIDs pq.Int64Array `db:"campaigns" json:"-"` CampaignIDs pq.Int64Array `db:"campaigns" json:"-"`
Lists []List `json:"lists"` Lists types.JSONText `db:"lists" json:"lists"`
// Pseudofield for getting the total number of subscribers // Pseudofield for getting the total number of subscribers
// in searches and queries. // in searches and queries.
Total int `db:"total" json:"-"` Total int `db:"total" json:"-"`
} }
type subLists struct {
SubscriberID int `db:"subscriber_id"`
Lists types.JSONText `db:"lists"`
}
// SubscriberAttribs is the map of key:value attributes of a subscriber. // SubscriberAttribs is the map of key:value attributes of a subscriber.
type SubscriberAttribs map[string]interface{} type SubscriberAttribs map[string]interface{}
@ -134,10 +139,7 @@ type Campaign struct {
Tags pq.StringArray `db:"tags" json:"tags"` Tags pq.StringArray `db:"tags" json:"tags"`
TemplateID int `db:"template_id" json:"template_id"` TemplateID int `db:"template_id" json:"template_id"`
MessengerID string `db:"messenger" json:"messenger"` MessengerID string `db:"messenger" json:"messenger"`
Lists types.JSONText `db:"lists" json:"lists"`
View int `db:"views" json:"views"`
Clicks int `db:"clicks" json:"clicks"`
// TemplateBody is joined in from templates by the next-campaigns query. // TemplateBody is joined in from templates by the next-campaigns query.
TemplateBody string `db:"template_body" json:"-"` TemplateBody string `db:"template_body" json:"-"`
Tpl *template.Template `json:"-"` Tpl *template.Template `json:"-"`
@ -149,12 +151,23 @@ type Campaign struct {
// CampaignMeta contains fields tracking a campaign's progress. // CampaignMeta contains fields tracking a campaign's progress.
type CampaignMeta struct { type CampaignMeta struct {
CampaignID int `db:"campaign_id" json:""`
Views int `db:"views" json:"views"`
Clicks int `db:"clicks" json:"clicks"`
// This is a list of {list_id, name} pairs unlike Subscriber.Lists[]
// because lists can be deleted after a campaign is finished, resulting
// in null lists data to be returned. For that reason, campaign_lists maintains
// campaign-list associations with a historical record of id + name that persist
// even after a list is deleted.
Lists types.JSONText `db:"lists" json:"lists"`
StartedAt null.Time `db:"started_at" json:"started_at"` StartedAt null.Time `db:"started_at" json:"started_at"`
ToSend int `db:"to_send" json:"to_send"` ToSend int `db:"to_send" json:"to_send"`
Sent int `db:"sent" json:"sent"` Sent int `db:"sent" json:"sent"`
} }
// Campaigns represents a slice of Campaign. // Campaigns represents a slice of Campaigns.
type Campaigns []Campaign type Campaigns []Campaign
// Media represents an uploaded media item. // Media represents an uploaded media item.
@ -179,29 +192,32 @@ type Template struct {
IsDefault bool `db:"is_default" json:"is_default"` IsDefault bool `db:"is_default" json:"is_default"`
} }
// GetIDs returns the list of subscriber IDs.
func (subs Subscribers) GetIDs() []int {
IDs := make([]int, len(subs))
for i, c := range subs {
IDs[i] = c.ID
}
return IDs
}
// LoadLists lazy loads the lists for all the subscribers // LoadLists lazy loads the lists for all the subscribers
// in the Subscribers slice and attaches them to their []Lists property. // in the Subscribers slice and attaches them to their []Lists property.
func (subs Subscribers) LoadLists(stmt *sqlx.Stmt) error { func (subs Subscribers) LoadLists(stmt *sqlx.Stmt) error {
var ( var sl []subLists
lists []List err := stmt.Select(&sl, pq.Array(subs.GetIDs()))
subIDs = make([]int, len(subs))
)
for i := 0; i < len(subs); i++ {
subIDs[i] = subs[i].ID
subs[i].Lists = make([]List, 0)
}
err := stmt.Select(&lists, pq.Array(subIDs))
if err != nil { if err != nil {
return err return err
} }
// Loop through each list and attach it to the subscribers by ID. if len(subs) != len(sl) {
for _, l := range lists { return errors.New("campaign stats count does not match")
for i := 0; i < len(subs); i++ {
if l.SubscriberID == subs[i].ID {
subs[i].Lists = append(subs[i].Lists, l)
} }
for i, s := range sl {
if s.SubscriberID == subs[i].ID {
subs[i].Lists = s.Lists
} }
} }
@ -221,6 +237,38 @@ func (s SubscriberAttribs) Scan(src interface{}) error {
return fmt.Errorf("Could not not decode type %T -> %T", src, s) return fmt.Errorf("Could not not decode type %T -> %T", src, s)
} }
// GetIDs returns the list of campaign IDs.
func (camps Campaigns) GetIDs() []int {
IDs := make([]int, len(camps))
for i, c := range camps {
IDs[i] = c.ID
}
return IDs
}
// LoadStats lazy loads campaign stats onto a list of campaigns.
func (camps Campaigns) LoadStats(stmt *sqlx.Stmt) error {
var meta []CampaignMeta
if err := stmt.Select(&meta, pq.Array(camps.GetIDs())); err != nil {
return err
}
if len(camps) != len(meta) {
return errors.New("campaign stats count does not match")
}
for i, c := range meta {
if c.CampaignID == camps[i].ID {
camps[i].Lists = c.Lists
camps[i].Views = c.Views
camps[i].Clicks = c.Clicks
}
}
return nil
}
// CompileTemplate compiles a campaign body template into its base // CompileTemplate compiles a campaign body template into its base
// template and sets the resultant template to Campaign.Tpl. // template and sets the resultant template to Campaign.Tpl.
func (c *Campaign) CompileTemplate(f template.FuncMap) error { func (c *Campaign) CompileTemplate(f template.FuncMap) error {

View file

@ -46,6 +46,7 @@ type Queries struct {
GetCampaign *sqlx.Stmt `query:"get-campaign"` GetCampaign *sqlx.Stmt `query:"get-campaign"`
GetCampaignForPreview *sqlx.Stmt `query:"get-campaign-for-preview"` GetCampaignForPreview *sqlx.Stmt `query:"get-campaign-for-preview"`
GetCampaignStats *sqlx.Stmt `query:"get-campaign-stats"` GetCampaignStats *sqlx.Stmt `query:"get-campaign-stats"`
GetCampaignStatus *sqlx.Stmt `query:"get-campaign-status"`
NextCampaigns *sqlx.Stmt `query:"next-campaigns"` NextCampaigns *sqlx.Stmt `query:"next-campaigns"`
NextCampaignSubscribers *sqlx.Stmt `query:"next-campaign-subscribers"` NextCampaignSubscribers *sqlx.Stmt `query:"next-campaign-subscribers"`
GetOneCampaignSubscriber *sqlx.Stmt `query:"get-one-campaign-subscriber"` GetOneCampaignSubscriber *sqlx.Stmt `query:"get-one-campaign-subscriber"`

View file

@ -9,10 +9,25 @@ SELECT * FROM subscribers WHERE CASE WHEN $1 > 0 THEN id = $1 ELSE uuid = $2 END
SELECT * FROM subscribers WHERE email=ANY($1); SELECT * FROM subscribers WHERE email=ANY($1);
-- name: get-subscriber-lists -- name: get-subscriber-lists
-- Get lists belonging to subscribers. -- Get lists associations of subscribers given a list of subscriber IDs.
SELECT lists.*, subscriber_lists.subscriber_id, subscriber_lists.status AS subscription_status FROM lists -- This query is used to lazy load given a list of subscriber IDs.
-- The query returns results in the same order as the given subscriber IDs, and for non-existent subscriber IDs,
-- the query still returns a row with 0 values. Thus, for lazy loading, the application simply iterate on the results in
-- the same order as the list of campaigns it would've queried and attach the results.
WITH subs AS (
SELECT subscriber_id, JSON_AGG(
ROW_TO_JSON(
(SELECT l FROM (SELECT subscriber_lists.status AS subscription_status, lists.*) l)
)
) AS lists FROM lists
LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id) LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
WHERE subscriber_lists.subscriber_id = ANY($1::INT[]); WHERE subscriber_lists.subscriber_id = ANY($1)
GROUP BY subscriber_id
)
SELECT id as subscriber_id,
COALESCE(s.lists, '[]') AS lists
FROM (SELECT id FROM UNNEST($1) AS id) x
LEFT JOIN subs AS s ON (s.subscriber_id = id);
-- name: insert-subscriber -- name: insert-subscriber
WITH sub AS ( WITH sub AS (
@ -259,56 +274,42 @@ INSERT INTO campaign_lists (campaign_id, list_id, list_name)
-- there's a COUNT() OVER() that still returns the total result count -- there's a COUNT() OVER() that still returns the total result count
-- for pagination in the frontend, albeit being a field that'll repeat -- for pagination in the frontend, albeit being a field that'll repeat
-- with every resultant row. -- with every resultant row.
WITH camps AS ( SELECT COUNT(*) OVER () AS total, campaigns.*
SELECT COUNT(*) OVER () AS total, campaigns.*, (
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(l)), '[]') FROM (
SELECT COALESCE(campaign_lists.list_id, 0) AS id,
campaign_lists.list_name AS name
FROM campaign_lists WHERE campaign_lists.campaign_id = campaigns.id
) l
) AS lists
FROM campaigns FROM campaigns
WHERE ($1 = 0 OR id = $1) WHERE ($1 = 0 OR id = $1)
AND status=ANY(CASE WHEN ARRAY_LENGTH($2::campaign_status[], 1) != 0 THEN $2::campaign_status[] ELSE ARRAY[status] END) AND status=ANY(CASE WHEN ARRAY_LENGTH($2::campaign_status[], 1) != 0 THEN $2::campaign_status[] ELSE ARRAY[status] END)
AND ($3 = '' OR (to_tsvector(name || subject) @@ to_tsquery($3))) AND ($3 = '' OR (to_tsvector(name || subject) @@ to_tsquery($3)))
ORDER BY created_at DESC OFFSET $4 LIMIT $5 ORDER BY created_at DESC OFFSET $4 LIMIT $5;
), views AS (
SELECT campaign_id, COUNT(campaign_id) as num FROM campaign_views
WHERE campaign_id = ANY(SELECT id FROM camps)
GROUP BY campaign_id
),
clicks AS (
SELECT campaign_id, COUNT(campaign_id) as num FROM link_clicks
WHERE campaign_id = ANY(SELECT id FROM camps)
GROUP BY campaign_id
)
SELECT *,
COALESCE(v.num, 0) AS views,
COALESCE(c.num, 0) AS clicks
FROM camps
LEFT JOIN views AS v ON (v.campaign_id = camps.id)
LEFT JOIN clicks AS c ON (c.campaign_id = camps.id)
ORDER BY camps.created_at DESC;
-- name: get-campaign -- name: get-campaign
WITH camp AS ( SELECT * FROM campaigns WHERE id = $1;
SELECT * FROM campaigns WHERE id = $1
-- name: get-campaign-stats
-- This query is used to lazy load campaign stats (views, counts, list of lists) given a list of campaign IDs.
-- The query returns results in the same order as the given campaign IDs, and for non-existent campaign IDs,
-- the query still returns a row with 0 values. Thus, for lazy loading, the application simply iterate on the results in
-- the same order as the list of campaigns it would've queried and attach the results.
WITH lists AS (
SELECT campaign_id, JSON_AGG(JSON_BUILD_OBJECT('id', list_id, 'name', list_name)) AS lists FROM campaign_lists
WHERE campaign_id = ANY($1) GROUP BY campaign_id
), views AS ( ), views AS (
SELECT campaign_id, COUNT(campaign_id) as num FROM campaign_views SELECT campaign_id, COUNT(campaign_id) as num FROM campaign_views
WHERE campaign_id = ANY(SELECT id FROM camp) WHERE campaign_id = ANY($1)
GROUP BY campaign_id GROUP BY campaign_id
), ),
clicks AS ( clicks AS (
SELECT campaign_id, COUNT(campaign_id) as num FROM link_clicks SELECT campaign_id, COUNT(campaign_id) as num FROM link_clicks
WHERE campaign_id = ANY(SELECT id FROM camp) WHERE campaign_id = ANY($1)
GROUP BY campaign_id GROUP BY campaign_id
) )
SELECT *, SELECT id as campaign_id,
COALESCE(v.num, 0) AS views, COALESCE(v.num, 0) AS views,
COALESCE(c.num, 0) AS clicks COALESCE(c.num, 0) AS clicks,
FROM camp COALESCE(l.lists, '[]') AS lists
LEFT JOIN views AS v ON (v.campaign_id = camp.id) FROM (SELECT id FROM UNNEST($1) AS id) x
LEFT JOIN clicks AS c ON (c.campaign_id = camp.id); LEFT JOIN lists AS l ON (l.campaign_id = id)
LEFT JOIN views AS v ON (v.campaign_id = id)
LEFT JOIN clicks AS c ON (c.campaign_id = id);
-- name: get-campaign-for-preview -- name: get-campaign-for-preview
SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body, SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body,
@ -323,7 +324,7 @@ FROM campaigns
LEFT JOIN templates ON (templates.id = campaigns.template_id) LEFT JOIN templates ON (templates.id = campaigns.template_id)
WHERE campaigns.id = $1; WHERE campaigns.id = $1;
-- name: get-campaign-stats -- name: get-campaign-status
SELECT id, status, to_send, sent, started_at, updated_at SELECT id, status, to_send, sent, started_at, updated_at
FROM campaigns FROM campaigns
WHERE status=$1; WHERE status=$1;