normalize hostname and pathname columns

to save on disk storage
This commit is contained in:
Danny van Kooten 2018-11-12 14:45:21 +01:00
parent 69986d9215
commit dbcadcd737
39 changed files with 415 additions and 43 deletions

BIN
mc4wp.db.orig Normal file

Binary file not shown.

View File

@ -40,7 +40,17 @@ func (agg *Aggregator) getPageStats(r *results, siteID int64, t time.Time, hostn
return stats, nil return stats, nil
} }
stats, err := agg.database.GetPageStats(siteID, t, hostname, pathname) hostnameID, err := agg.database.HostnameID(hostname)
if err != nil {
return nil, err
}
pathnameID, err := agg.database.PathnameID(pathname)
if err != nil {
return nil, err
}
stats, err := agg.database.GetPageStats(siteID, t, hostnameID, pathnameID)
if err != nil && err != datastore.ErrNoResults { if err != nil && err != datastore.ErrNoResults {
return nil, err return nil, err
} }
@ -49,8 +59,8 @@ func (agg *Aggregator) getPageStats(r *results, siteID int64, t time.Time, hostn
stats = &models.PageStats{ stats = &models.PageStats{
SiteID: siteID, SiteID: siteID,
New: true, New: true,
Hostname: hostname, HostnameID: hostnameID,
Pathname: pathname, PathnameID: pathnameID,
Date: t, Date: t,
} }
@ -66,8 +76,18 @@ func (agg *Aggregator) getReferrerStats(r *results, siteID int64, t time.Time, h
return stats, nil return stats, nil
} }
hostnameID, err := agg.database.HostnameID(hostname)
if err != nil {
return nil, err
}
pathnameID, err := agg.database.PathnameID(pathname)
if err != nil {
return nil, err
}
// get from db // get from db
stats, err := agg.database.GetReferrerStats(siteID, t, hostname, pathname) stats, err := agg.database.GetReferrerStats(siteID, t, hostnameID, pathnameID)
if err != nil && err != datastore.ErrNoResults { if err != nil && err != datastore.ErrNoResults {
return nil, err return nil, err
} }
@ -76,14 +96,14 @@ func (agg *Aggregator) getReferrerStats(r *results, siteID int64, t time.Time, h
stats = &models.ReferrerStats{ stats = &models.ReferrerStats{
SiteID: siteID, SiteID: siteID,
New: true, New: true,
Hostname: hostname, HostnameID: hostnameID,
Pathname: pathname, PathnameID: pathnameID,
Date: t, Date: t,
Group: "", Group: "",
} }
// TODO: Abstract this // TODO: Abstract this so we can add more groupings
if strings.Contains(stats.Hostname, "www.google.") { if strings.Contains(hostname, "www.google.") {
stats.Group = "Google" stats.Group = "Google"
} }
} }

View File

@ -45,17 +45,21 @@ type Datastore interface {
DeletePageviews([]*models.Pageview) error DeletePageviews([]*models.Pageview) error
// page stats // page stats
GetPageStats(int64, time.Time, string, string) (*models.PageStats, error) GetPageStats(int64, time.Time, int64, int64) (*models.PageStats, error)
SavePageStats(*models.PageStats) error SavePageStats(*models.PageStats) error
GetAggregatedPageStats(int64, time.Time, time.Time, int64) ([]*models.PageStats, error) GetAggregatedPageStats(int64, time.Time, time.Time, int64) ([]*models.PageStats, error)
GetAggregatedPageStatsPageviews(int64, time.Time, time.Time) (int64, error) GetAggregatedPageStatsPageviews(int64, time.Time, time.Time) (int64, error)
// referrer stats // referrer stats
GetReferrerStats(int64, time.Time, string, string) (*models.ReferrerStats, error) GetReferrerStats(int64, time.Time, int64, int64) (*models.ReferrerStats, error)
SaveReferrerStats(*models.ReferrerStats) error SaveReferrerStats(*models.ReferrerStats) error
GetAggregatedReferrerStats(int64, time.Time, time.Time, int64) ([]*models.ReferrerStats, error) GetAggregatedReferrerStats(int64, time.Time, time.Time, int64) ([]*models.ReferrerStats, error)
GetAggregatedReferrerStatsPageviews(int64, time.Time, time.Time) (int64, error) GetAggregatedReferrerStatsPageviews(int64, time.Time, time.Time) (int64, error)
// hostnames
HostnameID(name string) (int64, error)
PathnameID(name string) (int64, error)
// misc // misc
Health() error Health() error
Close() error Close() error

View File

@ -0,0 +1,30 @@
package sqlstore
import (
"database/sql"
)
func (db *sqlstore) HostnameID(name string) (int64, error) {
var id int64
query := db.Rebind("SELECT id FROM hostnames WHERE name = ? LIMIT 1")
err := db.Get(&id, query, name)
if err == sql.ErrNoRows {
// Postgres does not support LastInsertID, so use a "... RETURNING" select query
query := db.Rebind(`INSERT INTO hostnames(name) VALUES(?)`)
if db.Driver == POSTGRES {
err := db.Get(&id, query+" RETURNING id", name)
return id, err
}
// MySQL and SQLite do support LastInsertID, so use that
r, err := db.Exec(query, name)
if err != nil {
return 0, err
}
return r.LastInsertId()
}
return id, err
}

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE hostnames(
id INTEGER AUTO_INCREMENT PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL
) CHARACTER SET=utf8;
-- +migrate Down
DROP TABLE IF EXISTS hostnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_hostnames_name;

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE pathnames(
id INTEGER AUTO_INCREMENT PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL
) CHARACTER SET=utf8;
-- +migrate Down
DROP TABLE IF EXISTS pathnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_pathnames_name;

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT IGNORE INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_page_stats;
INSERT IGNORE INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_referrer_stats;
-- +migrate Down

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT IGNORE INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_page_stats;
INSERT IGNORE INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_referrer_stats;
-- +migrate Down

View File

@ -0,0 +1,24 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_page_stats_old;
RENAME TABLE daily_page_stats TO daily_page_stats_old;
CREATE TABLE daily_page_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
entries INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
) CHARACTER SET=utf8;
INSERT INTO daily_page_stats
SELECT site_id, h.id, p.id, pageviews, visitors, entries, bounce_rate, known_durations, avg_duration, date
FROM daily_page_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_page_stats_old;
-- +migrate Down

View File

@ -0,0 +1,24 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_referrer_stats_old;
RENAME TABLE daily_referrer_stats TO daily_referrer_stats_old;
CREATE TABLE daily_referrer_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
groupname VARCHAR(255) NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
) CHARACTER SET=utf8;
INSERT INTO daily_referrer_stats
SELECT site_id, h.id, p.id, groupname, pageviews, visitors, bounce_rate, known_durations, avg_duration, date
FROM daily_referrer_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_referrer_stats_old;
-- +migrate Down

View File

@ -0,0 +1,7 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_daily_page_stats ON daily_page_stats(site_id, hostname_id, pathname_id, date);
CREATE UNIQUE INDEX unique_daily_referrer_stats ON daily_referrer_stats(site_id, hostname_id, pathname_id, date);
-- +migrate Down
DROP INDEX unique_daily_page_stats ON daily_page_stats;
DROP INDEX unique_daily_referrer_stats ON daily_referrer_stats;

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE hostnames(
id SERIAL PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL
);
-- +migrate Down
DROP TABLE IF EXISTS hostnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_hostnames_name;

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE pathnames(
id SERIAL PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL
);
-- +migrate Down
DROP TABLE IF EXISTS pathnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_pathnames_name;

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_page_stats;
INSERT INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_referrer_stats ON CONFLICT(name) DO NOTHING;
-- +migrate Down

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_page_stats ON CONFLICT(name) DO NOTHING; ;
INSERT INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_referrer_stats ON CONFLICT(name) DO NOTHING; ;
-- +migrate Down

View File

@ -0,0 +1,24 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_page_stats_old;
ALTER TABLE daily_page_stats RENAME TO daily_page_stats_old;
CREATE TABLE daily_page_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
entries INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
);
INSERT INTO daily_page_stats
SELECT site_id, h.id, p.id, pageviews, visitors, entries, bounce_rate, known_durations, avg_duration, date
FROM daily_page_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_page_stats_old;
-- +migrate Down

View File

@ -0,0 +1,24 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_referrer_stats_old;
ALTER TABLE daily_referrer_stats RENAME TO daily_referrer_stats_old;
CREATE TABLE daily_referrer_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
groupname VARCHAR(255) NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
);
INSERT INTO daily_referrer_stats
SELECT site_id, h.id, p.id, groupname, pageviews, visitors, bounce_rate, known_durations, avg_duration, date
FROM daily_referrer_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_referrer_stats_old;
-- +migrate Down

View File

@ -0,0 +1,7 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_daily_page_stats ON daily_page_stats(site_id, hostname_id, pathname_id, date);
CREATE UNIQUE INDEX unique_daily_referrer_stats ON daily_referrer_stats(site_id, hostname_id, pathname_id, date);
-- +migrate Down
DROP INDEX unique_daily_page_stats;
DROP INDEX unique_daily_referrer_stats;

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE hostnames(
id INTEGER PRIMARY KEY,
name VARCHAR(255) NOT NULL
);
-- +migrate Down
DROP TABLE IF EXISTS hostnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_hostnames_name;

View File

@ -0,0 +1,8 @@
-- +migrate Up
CREATE TABLE pathnames(
id INTEGER PRIMARY KEY,
name VARCHAR(255) NOT NULL
);
-- +migrate Down
DROP TABLE IF EXISTS pathnames;

View File

@ -0,0 +1,5 @@
-- +migrate Up
CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name);
-- +migrate Down
DROP INDEX IF EXISTS unique_pathnames_name;

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT OR IGNORE INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_page_stats;
INSERT OR IGNORE INTO hostnames(name) SELECT DISTINCT(hostname) FROM daily_referrer_stats;
-- +migrate Down

View File

@ -0,0 +1,6 @@
-- +migrate Up
INSERT OR IGNORE INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_page_stats;
INSERT OR IGNORE INTO pathnames(name) SELECT DISTINCT(pathname) FROM daily_referrer_stats;
-- +migrate Down

View File

@ -0,0 +1,24 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_page_stats_old;
ALTER TABLE daily_page_stats RENAME TO daily_page_stats_old;
CREATE TABLE daily_page_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
entries INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
);
INSERT INTO daily_page_stats
SELECT site_id, h.id, p.id, pageviews, visitors, entries, bounce_rate, known_durations, avg_duration, date
FROM daily_page_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_page_stats_old;
-- +migrate Down

View File

@ -0,0 +1,25 @@
-- +migrate Up
DROP TABLE IF EXISTS daily_referrer_stats_old;
ALTER TABLE daily_referrer_stats RENAME TO daily_referrer_stats_old;
CREATE TABLE daily_referrer_stats(
site_id INTEGER NOT NULL DEFAULT 1,
hostname_id INTEGER NOT NULL,
pathname_id INTEGER NOT NULL,
groupname VARCHAR(255) NULL,
pageviews INTEGER NOT NULL,
visitors INTEGER NOT NULL,
bounce_rate FLOAT NOT NULL,
known_durations INTEGER NOT NULL DEFAULT 0,
avg_duration FLOAT NOT NULL,
date DATE NOT NULL
);
INSERT INTO daily_referrer_stats
SELECT site_id, h.id, p.id, groupname, pageviews, visitors, bounce_rate, known_durations, avg_duration, date
FROM daily_referrer_stats_old s
LEFT JOIN hostnames h ON h.name = s.hostname
LEFT JOIN pathnames p ON p.name = s.pathname;
DROP TABLE daily_referrer_stats_old;
VACUUM;
-- +migrate Down

View File

@ -0,0 +1,9 @@
-- +migrate Up
DROP INDEX IF EXISTS unique_daily_page_stats;
DROP INDEX IF EXISTS unique_daily_referrer_stats;
CREATE UNIQUE INDEX unique_daily_page_stats ON daily_page_stats(site_id, hostname_id, pathname_id, date);
CREATE UNIQUE INDEX unique_daily_referrer_stats ON daily_referrer_stats(site_id, hostname_id, pathname_id, date);
-- +migrate Down
DROP INDEX IF EXISTS unique_daily_page_stats;
DROP INDEX IF EXISTS unique_daily_referrer_stats;

View File

@ -4,5 +4,4 @@ ALTER TABLE daily_site_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1;
-- +migrate Down -- +migrate Down
ALTER TABLE daily_site_stats DROP COLUMN site_id;

View File

@ -4,5 +4,4 @@ ALTER TABLE daily_page_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1;
-- +migrate Down -- +migrate Down
ALTER TABLE daily_page_stats DROP COLUMN site_id;

View File

@ -4,5 +4,4 @@ ALTER TABLE daily_referrer_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1;
-- +migrate Down -- +migrate Down
ALTER TABLE daily_referrer_stats DROP COLUMN site_id;

View File

@ -7,10 +7,10 @@ import (
"github.com/usefathom/fathom/pkg/models" "github.com/usefathom/fathom/pkg/models"
) )
func (db *sqlstore) GetPageStats(siteID int64, date time.Time, hostname string, pathname string) (*models.PageStats, error) { func (db *sqlstore) GetPageStats(siteID int64, date time.Time, hostnameID int64, pathnameID int64) (*models.PageStats, error) {
stats := &models.PageStats{New: false} stats := &models.PageStats{New: false}
query := db.Rebind(`SELECT * FROM daily_page_stats WHERE site_id = ? AND hostname = ? AND pathname = ? AND date = ? LIMIT 1`) query := db.Rebind(`SELECT * FROM daily_page_stats WHERE site_id = ? AND hostname_id = ? AND pathname_id = ? AND date = ? LIMIT 1`)
err := db.Get(stats, query, siteID, hostname, pathname, date.Format("2006-01-02")) err := db.Get(stats, query, siteID, hostnameID, pathnameID, date.Format("2006-01-02"))
if err == sql.ErrNoRows { if err == sql.ErrNoRows {
return nil, ErrNoResults return nil, ErrNoResults
} }
@ -27,28 +27,31 @@ func (db *sqlstore) SavePageStats(s *models.PageStats) error {
} }
func (db *sqlstore) insertPageStats(s *models.PageStats) error { func (db *sqlstore) insertPageStats(s *models.PageStats) error {
query := db.Rebind(`INSERT INTO daily_page_stats(pageviews, visitors, entries, bounce_rate, avg_duration, known_durations, site_id, hostname, pathname, date) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`) query := db.Rebind(`INSERT INTO daily_page_stats(pageviews, visitors, entries, bounce_rate, avg_duration, known_durations, site_id, hostname_id, pathname_id, date) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`)
_, err := db.Exec(query, s.Pageviews, s.Visitors, s.Entries, s.BounceRate, s.AvgDuration, s.KnownDurations, s.SiteID, s.Hostname, s.Pathname, s.Date.Format("2006-01-02")) _, err := db.Exec(query, s.Pageviews, s.Visitors, s.Entries, s.BounceRate, s.AvgDuration, s.KnownDurations, s.SiteID, s.HostnameID, s.PathnameID, s.Date.Format("2006-01-02"))
return err return err
} }
func (db *sqlstore) updatePageStats(s *models.PageStats) error { func (db *sqlstore) updatePageStats(s *models.PageStats) error {
query := db.Rebind(`UPDATE daily_page_stats SET pageviews = ?, visitors = ?, entries = ?, bounce_rate = ?, avg_duration = ?, known_durations = ? WHERE site_id = ? AND hostname = ? AND pathname = ? AND date = ?`) query := db.Rebind(`UPDATE daily_page_stats SET pageviews = ?, visitors = ?, entries = ?, bounce_rate = ?, avg_duration = ?, known_durations = ? WHERE site_id = ? AND hostname_id = ? AND pathname_id = ? AND date = ?`)
_, err := db.Exec(query, s.Pageviews, s.Visitors, s.Entries, s.BounceRate, s.AvgDuration, s.KnownDurations, s.SiteID, s.Hostname, s.Pathname, s.Date.Format("2006-01-02")) _, err := db.Exec(query, s.Pageviews, s.Visitors, s.Entries, s.BounceRate, s.AvgDuration, s.KnownDurations, s.SiteID, s.HostnameID, s.PathnameID, s.Date.Format("2006-01-02"))
return err return err
} }
func (db *sqlstore) GetAggregatedPageStats(siteID int64, startDate time.Time, endDate time.Time, limit int64) ([]*models.PageStats, error) { func (db *sqlstore) GetAggregatedPageStats(siteID int64, startDate time.Time, endDate time.Time, limit int64) ([]*models.PageStats, error) {
var result []*models.PageStats var result []*models.PageStats
query := db.Rebind(`SELECT query := db.Rebind(`SELECT
hostname, h.name AS hostname,
pathname, p.name AS pathname,
SUM(pageviews) AS pageviews, SUM(pageviews) AS pageviews,
SUM(visitors) AS visitors, SUM(visitors) AS visitors,
SUM(entries) AS entries, SUM(entries) AS entries,
COALESCE(SUM(entries*bounce_rate) / NULLIF(SUM(entries), 0), 0.00) AS bounce_rate, COALESCE(SUM(entries*bounce_rate) / NULLIF(SUM(entries), 0), 0.00) AS bounce_rate,
COALESCE(SUM(avg_duration*pageviews) / SUM(pageviews), 0.00) AS avg_duration COALESCE(SUM(pageviews*avg_duration) / SUM(pageviews), 0.00) AS avg_duration
FROM daily_page_stats WHERE site_id = ? AND date >= ? AND date <= ? FROM daily_page_stats s
LEFT JOIN hostnames h ON h.id = s.hostname_id
LEFT JOIN pathnames p ON p.id = s.pathname_id
WHERE site_id = ? AND date >= ? AND date <= ?
GROUP BY hostname, pathname GROUP BY hostname, pathname
ORDER BY pageviews DESC LIMIT ?`) ORDER BY pageviews DESC LIMIT ?`)
err := db.Select(&result, query, siteID, startDate.Format("2006-01-02"), endDate.Format("2006-01-02"), limit) err := db.Select(&result, query, siteID, startDate.Format("2006-01-02"), endDate.Format("2006-01-02"), limit)

View File

@ -0,0 +1,30 @@
package sqlstore
import (
"database/sql"
)
func (db *sqlstore) PathnameID(name string) (int64, error) {
var id int64
query := db.Rebind("SELECT id FROM pathnames WHERE name = ? LIMIT 1")
err := db.Get(&id, query, name)
if err == sql.ErrNoRows {
// Postgres does not support LastInsertID, so use a "... RETURNING" select query
query := db.Rebind(`INSERT INTO pathnames(name) VALUES(?)`)
if db.Driver == POSTGRES {
err := db.Get(&id, query+" RETURNING id", name)
return id, err
}
// MySQL and SQLite do support LastInsertID, so use that
r, err := db.Exec(query, name)
if err != nil {
return 0, err
}
return r.LastInsertId()
}
return id, err
}

View File

@ -7,10 +7,10 @@ import (
"github.com/usefathom/fathom/pkg/models" "github.com/usefathom/fathom/pkg/models"
) )
func (db *sqlstore) GetReferrerStats(siteID int64, date time.Time, hostname string, pathname string) (*models.ReferrerStats, error) { func (db *sqlstore) GetReferrerStats(siteID int64, date time.Time, hostnameID int64, pathnameID int64) (*models.ReferrerStats, error) {
stats := &models.ReferrerStats{New: false} stats := &models.ReferrerStats{New: false}
query := db.Rebind(`SELECT * FROM daily_referrer_stats WHERE site_id = ? AND date = ? AND hostname = ? AND pathname = ? LIMIT 1`) query := db.Rebind(`SELECT * FROM daily_referrer_stats WHERE site_id = ? AND date = ? AND hostname_id = ? AND pathname_id = ? LIMIT 1`)
err := db.Get(stats, query, siteID, date.Format("2006-01-02"), hostname, pathname) err := db.Get(stats, query, siteID, date.Format("2006-01-02"), hostnameID, pathnameID)
if err == sql.ErrNoRows { if err == sql.ErrNoRows {
return nil, ErrNoResults return nil, ErrNoResults
} }
@ -27,14 +27,14 @@ func (db *sqlstore) SaveReferrerStats(s *models.ReferrerStats) error {
} }
func (db *sqlstore) insertReferrerStats(s *models.ReferrerStats) error { func (db *sqlstore) insertReferrerStats(s *models.ReferrerStats) error {
query := db.Rebind(`INSERT INTO daily_referrer_stats(visitors, pageviews, bounce_rate, avg_duration, known_durations, groupname, site_id, hostname, pathname, date) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`) query := db.Rebind(`INSERT INTO daily_referrer_stats(visitors, pageviews, bounce_rate, avg_duration, known_durations, groupname, site_id, hostname_id, pathname_id, date) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`)
_, err := db.Exec(query, s.Visitors, s.Pageviews, s.BounceRate, s.AvgDuration, s.KnownDurations, s.Group, s.SiteID, s.Hostname, s.Pathname, s.Date.Format("2006-01-02")) _, err := db.Exec(query, s.Visitors, s.Pageviews, s.BounceRate, s.AvgDuration, s.KnownDurations, s.Group, s.SiteID, s.HostnameID, s.PathnameID, s.Date.Format("2006-01-02"))
return err return err
} }
func (db *sqlstore) updateReferrerStats(s *models.ReferrerStats) error { func (db *sqlstore) updateReferrerStats(s *models.ReferrerStats) error {
query := db.Rebind(`UPDATE daily_referrer_stats SET visitors = ?, pageviews = ?, bounce_rate = ?, avg_duration = ?, known_durations = ?, groupname = ? WHERE site_id = ? AND hostname = ? AND pathname = ? AND date = ?`) query := db.Rebind(`UPDATE daily_referrer_stats SET visitors = ?, pageviews = ?, bounce_rate = ?, avg_duration = ?, known_durations = ?, groupname = ? WHERE site_id = ? AND hostname_id = ? AND pathname_id = ? AND date = ?`)
_, err := db.Exec(query, s.Visitors, s.Pageviews, s.BounceRate, s.AvgDuration, s.KnownDurations, s.Group, s.SiteID, s.Hostname, s.Pathname, s.Date.Format("2006-01-02")) _, err := db.Exec(query, s.Visitors, s.Pageviews, s.BounceRate, s.AvgDuration, s.KnownDurations, s.Group, s.SiteID, s.HostnameID, s.PathnameID, s.Date.Format("2006-01-02"))
return err return err
} }
@ -42,14 +42,16 @@ func (db *sqlstore) GetAggregatedReferrerStats(siteID int64, startDate time.Time
var result []*models.ReferrerStats var result []*models.ReferrerStats
sql := `SELECT sql := `SELECT
MIN(hostname) AS hostname, h.name AS hostname,
MIN(pathname) AS pathname, p.name AS pathname,
COALESCE(MIN(groupname), '') AS groupname, COALESCE(groupname, '') AS groupname,
SUM(visitors) AS visitors, SUM(visitors) AS visitors,
SUM(pageviews) AS pageviews, SUM(pageviews) AS pageviews,
COALESCE(SUM(pageviews*NULLIF(bounce_rate, 0)) / SUM(pageviews), 0.00) AS bounce_rate, COALESCE(SUM(pageviews*NULLIF(bounce_rate, 0)) / SUM(pageviews), 0.00) AS bounce_rate,
COALESCE(SUM(avg_duration*pageviews) / SUM(pageviews), 0.00) AS avg_duration COALESCE(SUM(pageviews*avg_duration) / SUM(pageviews), 0.00) AS avg_duration
FROM daily_referrer_stats FROM daily_referrer_stats s
LEFT JOIN hostnames h ON h.id = s.hostname_id
LEFT JOIN pathnames p ON p.id = s.pathname_id
WHERE site_id = ? AND date >= ? AND date <= ? ` WHERE site_id = ? AND date >= ? AND date <= ? `
if db.Config.Driver == "sqlite3" { if db.Config.Driver == "sqlite3" {

View File

@ -7,6 +7,8 @@ import (
type PageStats struct { type PageStats struct {
New bool `db:"-" json:"-"` New bool `db:"-" json:"-"`
SiteID int64 `db:"site_id"` SiteID int64 `db:"site_id"`
HostnameID int64 `db:"hostname_id" json:"-"`
PathnameID int64 `db:"pathname_id" json:"-"`
Hostname string `db:"hostname"` Hostname string `db:"hostname"`
Pathname string `db:"pathname"` Pathname string `db:"pathname"`
Pageviews int64 `db:"pageviews"` Pageviews int64 `db:"pageviews"`

View File

@ -7,6 +7,8 @@ import (
type ReferrerStats struct { type ReferrerStats struct {
New bool `db:"-" json:"-"` New bool `db:"-" json:"-"`
SiteID int64 `db:"site_id"` SiteID int64 `db:"site_id"`
HostnameID int64 `db:"hostname_id" json:"-"`
PathnameID int64 `db:"pathname_id" json:"-"`
Hostname string `db:"hostname"` Hostname string `db:"hostname"`
Pathname string `db:"pathname"` Pathname string `db:"pathname"`
Group string `db:"groupname"` Group string `db:"groupname"`