From 93c952082cadf09845f9fc404e9248bf0594747e Mon Sep 17 00:00:00 2001 From: Kailash Nadh Date: Sat, 30 Mar 2019 12:31:24 +0530 Subject: [PATCH] Refactor campaigns query into two: 'query' and 'get' --- campaigns.go | 20 ++++++++++++-------- manager_db.go | 2 +- models/models.go | 2 +- queries.go | 3 ++- queries.sql | 26 +++++++++++++++++++++++--- 5 files changed, 39 insertions(+), 14 deletions(-) diff --git a/campaigns.go b/campaigns.go index d1223e1..0e1e47f 100644 --- a/campaigns.go +++ b/campaigns.go @@ -21,8 +21,12 @@ import ( // campaignReq is a wrapper over the Campaign model. type campaignReq struct { models.Campaign - MessengerID string `json:"messenger"` - Lists pq.Int64Array `json:"lists"` + + // This overrides Campaign.Lists to receive and + // write a list of int IDs during creation and updation. + // Campaign.Lists is JSONText for sending lists children + // to the outside world. + ListIDs pq.Int64Array `db:"-" json:"lists"` // This is only relevant to campaign test requests. SubscriberEmails pq.StringArray `json:"subscribers"` @@ -74,7 +78,7 @@ func handleGetCampaigns(c echo.Context) error { query = string(regexFullTextQuery.ReplaceAll([]byte(query), []byte("&"))) } - err := app.Queries.GetCampaigns.Select(&out.Results, id, pq.StringArray(status), query, pg.Offset, pg.Limit) + err := app.Queries.QueryCampaigns.Select(&out.Results, id, pq.StringArray(status), query, pg.Offset, pg.Limit) if err != nil { return echo.NewHTTPError(http.StatusInternalServerError, fmt.Sprintf("Error fetching campaigns: %s", pqErrMsg(err))) @@ -199,7 +203,7 @@ func handleCreateCampaign(c echo.Context) error { pq.StringArray(normalizeTags(o.Tags)), "email", o.TemplateID, - o.Lists, + o.ListIDs, ); err != nil { if err == sql.ErrNoRows { return echo.NewHTTPError(http.StatusBadRequest, @@ -230,7 +234,7 @@ func handleUpdateCampaign(c echo.Context) error { } var cm models.Campaign - if err := app.Queries.GetCampaigns.Get(&cm, id, "", 0, 1); err != nil { + if err := app.Queries.GetCampaign.Get(&cm, id); err != nil { if err == sql.ErrNoRows { return echo.NewHTTPError(http.StatusBadRequest, "Campaign not found.") } @@ -263,7 +267,7 @@ func handleUpdateCampaign(c echo.Context) error { o.SendAt, pq.StringArray(normalizeTags(o.Tags)), o.TemplateID, - o.Lists) + o.ListIDs) if err != nil { return echo.NewHTTPError(http.StatusInternalServerError, fmt.Sprintf("Error updating campaign: %s", pqErrMsg(err))) @@ -288,7 +292,7 @@ func handleUpdateCampaignStatus(c echo.Context) error { } var cm models.Campaign - if err := app.Queries.GetCampaigns.Get(&cm, id, "", 0, 1); err != nil { + if err := app.Queries.GetCampaign.Get(&cm, id); err != nil { if err == sql.ErrNoRows { return echo.NewHTTPError(http.StatusBadRequest, "Campaign not found.") } @@ -361,7 +365,7 @@ func handleDeleteCampaign(c echo.Context) error { } var cm models.Campaign - if err := app.Queries.GetCampaigns.Get(&cm, id, "", 0, 1); err != nil { + if err := app.Queries.GetCampaign.Get(&cm, id); err != nil { if err == sql.ErrNoRows { return echo.NewHTTPError(http.StatusBadRequest, "Campaign not found.") } diff --git a/manager_db.go b/manager_db.go index bff11b2..96a6c57 100644 --- a/manager_db.go +++ b/manager_db.go @@ -38,7 +38,7 @@ func (r *runnerDB) NextSubscribers(campID, limit int) ([]*models.Subscriber, err // GetCampaign fetches a campaign from the database. func (r *runnerDB) GetCampaign(campID int) (*models.Campaign, error) { var out = &models.Campaign{} - err := r.queries.GetCampaigns.Get(out, campID, "", 0, 1) + err := r.queries.GetCampaign.Get(out, campID) return out, err } diff --git a/models/models.go b/models/models.go index f008365..0186044 100644 --- a/models/models.go +++ b/models/models.go @@ -134,7 +134,7 @@ type Campaign struct { Tags pq.StringArray `db:"tags" json:"tags"` TemplateID int `db:"template_id" json:"template_id"` MessengerID string `db:"messenger" json:"messenger"` - Lists types.JSONText `json:"lists"` + Lists types.JSONText `db:"lists" json:"lists"` View int `db:"views" json:"views"` Clicks int `db:"clicks" json:"clicks"` diff --git a/queries.go b/queries.go index 53e9052..6034acb 100644 --- a/queries.go +++ b/queries.go @@ -42,7 +42,8 @@ type Queries struct { DeleteLists *sqlx.Stmt `query:"delete-lists"` CreateCampaign *sqlx.Stmt `query:"create-campaign"` - GetCampaigns *sqlx.Stmt `query:"get-campaigns"` + QueryCampaigns *sqlx.Stmt `query:"query-campaigns"` + GetCampaign *sqlx.Stmt `query:"get-campaign"` GetCampaignForPreview *sqlx.Stmt `query:"get-campaign-for-preview"` GetCampaignStats *sqlx.Stmt `query:"get-campaign-stats"` NextCampaigns *sqlx.Stmt `query:"next-campaigns"` diff --git a/queries.sql b/queries.sql index 288152f..46cd027 100644 --- a/queries.sql +++ b/queries.sql @@ -252,7 +252,7 @@ INSERT INTO campaign_lists (campaign_id, list_id, list_name) (SELECT (SELECT id FROM camp), id, name FROM lists WHERE id=ANY($11::INT[])) RETURNING (SELECT id FROM camp); --- name: get-campaigns +-- name: query-campaigns -- Here, 'lists' is returned as an aggregated JSON array from campaign_lists because -- the list reference may have been deleted. -- While the results are sliced using offset+limit, @@ -290,6 +290,26 @@ 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 +WITH camp AS ( + SELECT * FROM campaigns WHERE id = $1 +), views AS ( + SELECT campaign_id, COUNT(campaign_id) as num FROM campaign_views + WHERE campaign_id = ANY(SELECT id FROM camp) + GROUP BY campaign_id +), +clicks AS ( + SELECT campaign_id, COUNT(campaign_id) as num FROM link_clicks + WHERE campaign_id = ANY(SELECT id FROM camp) + GROUP BY campaign_id +) +SELECT *, + COALESCE(v.num, 0) AS views, + COALESCE(c.num, 0) AS clicks +FROM camp +LEFT JOIN views AS v ON (v.campaign_id = camp.id) +LEFT JOIN clicks AS c ON (c.campaign_id = camp.id); + -- name: get-campaign-for-preview SELECT campaigns.*, COALESCE(templates.body, (SELECT body FROM templates WHERE is_default = true LIMIT 1)) AS template_body, ( @@ -394,9 +414,9 @@ WITH camp AS ( updated_at=NOW() WHERE id = $1 RETURNING id ), - -- Reset the relationships d AS ( - DELETE FROM campaign_lists WHERE campaign_id = $1 + -- Reset list relationships + DELETE FROM campaign_lists WHERE campaign_id = $1 AND NOT(list_id = ANY($10)) ) INSERT INTO campaign_lists (campaign_id, list_id, list_name) (SELECT $1 as campaign_id, id, name FROM lists WHERE id=ANY($10::INT[]))