Skip to content

Commit 3550d54

Browse files
committed
Fix incorrect analytics count. Closes #712.
1 parent fb3c429 commit 3550d54

File tree

3 files changed

+43
-30
lines changed

3 files changed

+43
-30
lines changed

cmd/init.go

Lines changed: 15 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -283,19 +283,25 @@ func readQueries(sqlFile string, db *sqlx.DB, fs stuffbin.FileSystem) goyesql.Qu
283283

284284
// prepareQueries queries prepares a query map and returns a *Queries
285285
func prepareQueries(qMap goyesql.Queries, db *sqlx.DB, ko *koanf.Koanf) *models.Queries {
286-
// The campaign view/click count queries have a COUNT(%s) placeholder that should either
287-
// be substituted with * to pull non-unique rows when individual subscriber tracking is off
288-
// as all subscriber_ids will be null, or with DISTINCT subscriber_id when tracking is on
289-
// to only pull unique rows per subscriber.
290-
sel := "*"
286+
var (
287+
countQuery = "get-campaign-analytics-counts"
288+
linkSel = "*"
289+
)
291290
if ko.Bool("privacy.individual_tracking") {
292-
sel = "DISTINCT subscriber_id"
291+
countQuery = "get-campaign-analytics-unique-counts"
292+
linkSel = "DISTINCT subscriber_id"
293293
}
294294

295-
keys := []string{"get-campaign-view-counts", "get-campaign-click-counts", "get-campaign-link-counts"}
296-
for _, k := range keys {
297-
qMap[k].Query = fmt.Sprintf(qMap[k].Query, sel)
295+
// These don't exist in the SQL file but are in the queries struct to be prepared.
296+
qMap["get-campaign-view-counts"] = &goyesql.Query{
297+
Query: fmt.Sprintf(qMap[countQuery].Query, "campaign_views"),
298+
Tags: map[string]string{"name": "get-campaign-view-counts"},
299+
}
300+
qMap["get-campaign-click-counts"] = &goyesql.Query{
301+
Query: fmt.Sprintf(qMap[countQuery].Query, "link_clicks"),
302+
Tags: map[string]string{"name": "get-campaign-click-counts"},
298303
}
304+
qMap["get-campaign-link-counts"].Query = fmt.Sprintf(qMap["get-campaign-link-counts"].Query, linkSel)
299305

300306
// Scan and prepare all queries.
301307
var q models.Queries

models/queries.go

Lines changed: 16 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -50,16 +50,22 @@ type Queries struct {
5050
UpdateListsDate *sqlx.Stmt `query:"update-lists-date"`
5151
DeleteLists *sqlx.Stmt `query:"delete-lists"`
5252

53-
CreateCampaign *sqlx.Stmt `query:"create-campaign"`
54-
QueryCampaigns string `query:"query-campaigns"`
55-
GetCampaign *sqlx.Stmt `query:"get-campaign"`
56-
GetCampaignForPreview *sqlx.Stmt `query:"get-campaign-for-preview"`
57-
GetCampaignStats *sqlx.Stmt `query:"get-campaign-stats"`
58-
GetCampaignStatus *sqlx.Stmt `query:"get-campaign-status"`
59-
GetCampaignViewCounts *sqlx.Stmt `query:"get-campaign-view-counts"`
60-
GetCampaignClickCounts *sqlx.Stmt `query:"get-campaign-click-counts"`
61-
GetCampaignLinkCounts *sqlx.Stmt `query:"get-campaign-link-counts"`
62-
GetCampaignBounceCounts *sqlx.Stmt `query:"get-campaign-bounce-counts"`
53+
CreateCampaign *sqlx.Stmt `query:"create-campaign"`
54+
QueryCampaigns string `query:"query-campaigns"`
55+
GetCampaign *sqlx.Stmt `query:"get-campaign"`
56+
GetCampaignForPreview *sqlx.Stmt `query:"get-campaign-for-preview"`
57+
GetCampaignStats *sqlx.Stmt `query:"get-campaign-stats"`
58+
GetCampaignStatus *sqlx.Stmt `query:"get-campaign-status"`
59+
60+
// These two queries are read as strings and based on settings.individual_tracking=on/off,
61+
// are interpolated and copied to view and click counts. Same query, different tables.
62+
GetCampaignAnalyticsCounts string `query:"get-campaign-analytics-counts"`
63+
GetCampaignAnalyticsCountsUnique string `query:"get-campaign-analytics-unique-counts"`
64+
GetCampaignViewCounts *sqlx.Stmt `query:"get-campaign-view-counts"`
65+
GetCampaignClickCounts *sqlx.Stmt `query:"get-campaign-click-counts"`
66+
GetCampaignLinkCounts *sqlx.Stmt `query:"get-campaign-link-counts"`
67+
GetCampaignBounceCounts *sqlx.Stmt `query:"get-campaign-bounce-counts"`
68+
6369
NextCampaigns *sqlx.Stmt `query:"next-campaigns"`
6470
NextCampaignSubscribers *sqlx.Stmt `query:"next-campaign-subscribers"`
6571
GetOneCampaignSubscriber *sqlx.Stmt `query:"get-one-campaign-subscriber"`

queries.sql

Lines changed: 12 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -569,27 +569,28 @@ u AS (
569569
)
570570
SELECT * FROM camps;
571571

572-
-- name: get-campaign-view-counts
573-
-- raw: true
574-
-- %s = * or DISTINCT subscriber_id (prepared based on based on individual tracking=on/off). Prepared on boot.
572+
-- name: get-campaign-analytics-unique-counts
575573
WITH intval AS (
576574
-- For intervals < a week, aggregate counts hourly, otherwise daily.
577575
SELECT CASE WHEN (EXTRACT (EPOCH FROM ($3::TIMESTAMP - $2::TIMESTAMP)) / 86400) >= 7 THEN 'day' ELSE 'hour' END
578-
)
579-
SELECT campaign_id, COUNT(%s) AS "count", DATE_TRUNC((SELECT * FROM intval), created_at) AS "timestamp"
580-
FROM campaign_views
576+
),
577+
uniqIDs AS (
578+
SELECT DISTINCT ON(subscriber_id) subscriber_id, campaign_id, DATE_TRUNC((SELECT * FROM intval), created_at) AS "timestamp"
579+
FROM %s
581580
WHERE campaign_id=ANY($1) AND created_at >= $2 AND created_at <= $3
582-
GROUP BY campaign_id, "timestamp" ORDER BY "timestamp" ASC;
581+
ORDER BY subscriber_id, "timestamp"
582+
)
583+
SELECT COUNT(*) AS "count", campaign_id, "timestamp"
584+
FROM uniqIDs GROUP BY campaign_id, "timestamp";
583585

584-
-- name: get-campaign-click-counts
586+
-- name: get-campaign-analytics-counts
585587
-- raw: true
586-
-- %s = * or DISTINCT subscriber_id (prepared based on based on individual tracking=on/off). Prepared on boot.
587588
WITH intval AS (
588589
-- For intervals < a week, aggregate counts hourly, otherwise daily.
589590
SELECT CASE WHEN (EXTRACT (EPOCH FROM ($3::TIMESTAMP - $2::TIMESTAMP)) / 86400) >= 7 THEN 'day' ELSE 'hour' END
590591
)
591-
SELECT campaign_id, COUNT(%s) AS "count", DATE_TRUNC((SELECT * FROM intval), created_at) AS "timestamp"
592-
FROM link_clicks
592+
SELECT campaign_id, COUNT(*) AS "count", DATE_TRUNC((SELECT * FROM intval), created_at) AS "timestamp"
593+
FROM %s
593594
WHERE campaign_id=ANY($1) AND created_at >= $2 AND created_at <= $3
594595
GROUP BY campaign_id, "timestamp" ORDER BY "timestamp" ASC;
595596

0 commit comments

Comments
 (0)