diff --git a/cmd/queries.go b/cmd/queries.go index ed55331b..33bc3e0c 100644 --- a/cmd/queries.go +++ b/cmd/queries.go @@ -35,6 +35,7 @@ type Queries struct { // Non-prepared arbitrary subscriber queries. QuerySubscribers string `query:"query-subscribers"` + QuerySubscribersCount string `query:"query-subscribers-count"` QuerySubscribersForExport string `query:"query-subscribers-for-export"` QuerySubscribersTpl string `query:"query-subscribers-template"` DeleteSubscribersByQuery string `query:"delete-subscribers-by-query"` diff --git a/cmd/subscribers.go b/cmd/subscribers.go index 00aa13f2..ab874e8c 100644 --- a/cmd/subscribers.go +++ b/cmd/subscribers.go @@ -112,7 +112,7 @@ func handleQuerySubscribers(c echo.Context) error { query = sanitizeSQLExp(c.FormValue("query")) orderBy = c.FormValue("order_by") order = c.FormValue("order") - out subsWrap + out = subsWrap{Results: make([]models.Subscriber, 0, 1)} ) listIDs := pq.Int64Array{} @@ -130,15 +130,15 @@ func handleQuerySubscribers(c echo.Context) error { // Sort params. if !strSliceContains(orderBy, subQuerySortFields) { - orderBy = "updated_at" + orderBy = "subscribers.id" } if order != sortAsc && order != sortDesc { - order = sortAsc + order = sortDesc } - stmt := fmt.Sprintf(app.queries.QuerySubscribers, cond, orderBy, order) - - // Create a readonly transaction to prevent mutations. + // Create a readonly transaction that just does COUNT() to obtain the count of results + // and to ensure that the arbitrary query is indeed readonly. + stmt := fmt.Sprintf(app.queries.QuerySubscribersCount, cond) tx, err := app.db.BeginTxx(context.Background(), &sql.TxOptions{ReadOnly: true}) if err != nil { app.log.Printf("error preparing subscriber query: %v", err) @@ -147,7 +147,21 @@ func handleQuerySubscribers(c echo.Context) error { } defer tx.Rollback() - // Run the query. stmt is the raw SQL query. + // Execute the readonly query and get the count of results. + var total = 0 + if err := tx.Get(&total, stmt, listIDs); err != nil { + return echo.NewHTTPError(http.StatusInternalServerError, + app.i18n.Ts("globals.messages.errorFetching", + "name", "{globals.terms.subscribers}", "error", pqErrMsg(err))) + } + + // No results. + if total == 0 { + return c.JSON(http.StatusOK, okResp{out}) + } + + // Run the query again and fetch the actual data. stmt is the raw SQL query. + stmt = fmt.Sprintf(app.queries.QuerySubscribers, cond, orderBy, order) if err := tx.Select(&out.Results, stmt, listIDs, pg.Offset, pg.Limit); err != nil { return echo.NewHTTPError(http.StatusInternalServerError, app.i18n.Ts("globals.messages.errorFetching", @@ -169,7 +183,7 @@ func handleQuerySubscribers(c echo.Context) error { } // Meta. - out.Total = out.Results[0].Total + out.Total = total out.Page = pg.Page out.PerPage = pg.PerPage diff --git a/frontend/src/views/Subscribers.vue b/frontend/src/views/Subscribers.vue index 3969ffb3..7f34462f 100644 --- a/frontend/src/views/Subscribers.vue +++ b/frontend/src/views/Subscribers.vue @@ -20,7 +20,7 @@
-
+
{ - this.bulk.checked = []; + querySubscribers(params) { + this.queryParams = { ...this.queryParams, ...params }; + + this.$nextTick(() => { + this.$api.getSubscribers({ + list_id: this.queryParams.listID, + query: this.queryParams.queryExp, + page: this.queryParams.page, + order_by: this.queryParams.orderBy, + order: this.queryParams.order, + }).then(() => { + this.bulk.checked = []; + }); }); }, diff --git a/internal/migrations/v2.0.0.go b/internal/migrations/v2.0.0.go index 92f8dbac..7e16452e 100644 --- a/internal/migrations/v2.0.0.go +++ b/internal/migrations/v2.0.0.go @@ -67,6 +67,9 @@ func V2_0_0(db *sqlx.DB, fs stuffbin.FileSystem, ko *koanf.Koanf) error { ALTER TABLE campaign_lists ADD COLUMN IF NOT EXISTS id BIGSERIAL PRIMARY KEY; END IF; END$$; + + CREATE INDEX IF NOT EXISTS idx_views_date ON campaign_views((TIMEZONE('UTC', created_at)::DATE)); + CREATE INDEX IF NOT EXISTS idx_clicks_date ON link_clicks((TIMEZONE('UTC', created_at)::DATE)); `); err != nil { return err } diff --git a/models/models.go b/models/models.go index f8c4f970..1f5ffa92 100644 --- a/models/models.go +++ b/models/models.go @@ -126,10 +126,6 @@ type Subscriber struct { Attribs SubscriberAttribs `db:"attribs" json:"attribs"` Status string `db:"status" json:"status"` Lists types.JSONText `db:"lists" json:"lists"` - - // Pseudofield for getting the total number of subscribers - // in searches and queries. - Total int `db:"total" json:"-"` } type subLists struct { SubscriberID int `db:"subscriber_id"` diff --git a/queries.sql b/queries.sql index 84a2b56e..f2fdf719 100644 --- a/queries.sql +++ b/queries.sql @@ -233,7 +233,7 @@ SELECT (SELECT email FROM prof) as email, -- for pagination in the frontend, albeit being a field that'll repeat -- with every resultant row. -- %s = arbitrary expression, %s = order by field, %s = order direction -SELECT COUNT(*) OVER () AS total, subscribers.* FROM subscribers +SELECT subscribers.* FROM subscribers LEFT JOIN subscriber_lists ON ( -- Optional list filtering. @@ -244,6 +244,17 @@ SELECT COUNT(*) OVER () AS total, subscribers.* FROM subscribers %s ORDER BY %s %s OFFSET $2 LIMIT (CASE WHEN $3 = 0 THEN NULL ELSE $3 END); +-- name: query-subscribers-count +-- Replica of query-subscribers for obtaining the results count. +SELECT COUNT(*) AS total FROM subscribers + LEFT JOIN subscriber_lists + ON ( + -- Optional list filtering. + (CASE WHEN CARDINALITY($1::INT[]) > 0 THEN true ELSE false END) + AND subscriber_lists.subscriber_id = subscribers.id + ) + WHERE subscriber_lists.list_id = ALL($1::INT[]) %s; + -- name: query-subscribers-for-export -- raw: true -- Unprepared statement for issuring arbitrary WHERE conditions for @@ -773,26 +784,43 @@ INSERT INTO link_clicks (campaign_id, subscriber_id, link_id) VALUES( -- name: get-dashboard-charts WITH clicks AS ( - -- Clicks by day for the last 3 months SELECT JSON_AGG(ROW_TO_JSON(row)) - FROM (SELECT COUNT(*) AS count, created_at::DATE as date - FROM link_clicks GROUP by date ORDER BY date DESC LIMIT 100 + FROM ( + WITH viewDates AS ( + SELECT TIMEZONE('UTC', created_at)::DATE AS to_date, + TIMEZONE('UTC', created_at)::DATE - INTERVAL '30 DAY' AS from_date + FROM link_clicks ORDER BY id DESC LIMIT 1 + ) + SELECT COUNT(*) AS count, created_at::DATE as date FROM link_clicks + -- use > between < to force the use of the date index. + WHERE TIMEZONE('UTC', created_at)::DATE BETWEEN (SELECT from_date FROM viewDates) AND (SELECT to_date FROM viewDates) + GROUP by date ORDER BY date ) row ), views AS ( - -- Views by day for the last 3 months SELECT JSON_AGG(ROW_TO_JSON(row)) - FROM (SELECT COUNT(*) AS count, created_at::DATE as date - FROM campaign_views GROUP by date ORDER BY date DESC LIMIT 100 + FROM ( + WITH viewDates AS ( + SELECT TIMEZONE('UTC', created_at)::DATE AS to_date, + TIMEZONE('UTC', created_at)::DATE - INTERVAL '30 DAY' AS from_date + FROM campaign_views ORDER BY id DESC LIMIT 1 + ) + SELECT COUNT(*) AS count, created_at::DATE as date FROM campaign_views + -- use > between < to force the use of the date index. + WHERE TIMEZONE('UTC', created_at)::DATE BETWEEN (SELECT from_date FROM viewDates) AND (SELECT to_date FROM viewDates) + GROUP by date ORDER BY date ) row ) SELECT JSON_BUILD_OBJECT('link_clicks', COALESCE((SELECT * FROM clicks), '[]'), 'campaign_views', COALESCE((SELECT * FROM views), '[]')); -- name: get-dashboard-counts +WITH subs AS ( + SELECT COUNT(*) AS num, status FROM subscribers GROUP BY status +) SELECT JSON_BUILD_OBJECT('subscribers', JSON_BUILD_OBJECT( - 'total', (SELECT COUNT(*) FROM subscribers), - 'blocklisted', (SELECT COUNT(*) FROM subscribers WHERE status='blocklisted'), + 'total', (SELECT SUM(num) FROM subs), + 'blocklisted', (SELECT num FROM subs WHERE status='blocklisted'), 'orphans', ( SELECT COUNT(id) FROM subscribers LEFT JOIN subscriber_lists ON (subscribers.id = subscriber_lists.subscriber_id) diff --git a/schema.sql b/schema.sql index 8a4f41b9..cd5b3dbe 100644 --- a/schema.sql +++ b/schema.sql @@ -125,6 +125,7 @@ CREATE TABLE campaign_views ( ); 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); +DROP INDEX IF EXISTS idx_views_date; CREATE INDEX idx_views_date ON campaign_views((TIMEZONE('UTC', created_at)::DATE)); -- media DROP TABLE IF EXISTS media CASCADE; @@ -159,6 +160,7 @@ CREATE TABLE link_clicks ( 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); +DROP INDEX IF EXISTS idx_clicks_date; CREATE INDEX idx_clicks_date ON link_clicks((TIMEZONE('UTC', created_at)::DATE)); -- settings DROP TABLE IF EXISTS settings CASCADE; @@ -230,3 +232,4 @@ CREATE TABLE bounces ( DROP INDEX IF EXISTS idx_bounces_sub_id; CREATE INDEX idx_bounces_sub_id ON bounces(subscriber_id); DROP INDEX IF EXISTS idx_bounces_camp_id; CREATE INDEX idx_bounces_camp_id ON bounces(campaign_id); DROP INDEX IF EXISTS idx_bounces_source; CREATE INDEX idx_bounces_source ON bounces(source); +DROP INDEX IF EXISTS idx_bounces_date; CREATE INDEX idx_bounces_date ON bounces((TIMEZONE('UTC', created_at)::DATE));