diff --git a/mc4wp.db.orig b/mc4wp.db.orig new file mode 100644 index 0000000..6bf25c1 Binary files /dev/null and b/mc4wp.db.orig differ diff --git a/pkg/aggregator/store.go b/pkg/aggregator/store.go index a01076c..1ba55e3 100644 --- a/pkg/aggregator/store.go +++ b/pkg/aggregator/store.go @@ -40,18 +40,28 @@ func (agg *Aggregator) getPageStats(r *results, siteID int64, t time.Time, hostn 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 { return nil, err } if stats == nil { stats = &models.PageStats{ - SiteID: siteID, - New: true, - Hostname: hostname, - Pathname: pathname, - Date: t, + SiteID: siteID, + New: true, + HostnameID: hostnameID, + PathnameID: pathnameID, + Date: t, } } @@ -66,24 +76,34 @@ func (agg *Aggregator) getReferrerStats(r *results, siteID int64, t time.Time, h 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 - stats, err := agg.database.GetReferrerStats(siteID, t, hostname, pathname) + stats, err := agg.database.GetReferrerStats(siteID, t, hostnameID, pathnameID) if err != nil && err != datastore.ErrNoResults { return nil, err } if stats == nil { stats = &models.ReferrerStats{ - SiteID: siteID, - New: true, - Hostname: hostname, - Pathname: pathname, - Date: t, - Group: "", + SiteID: siteID, + New: true, + HostnameID: hostnameID, + PathnameID: pathnameID, + Date: t, + Group: "", } - // TODO: Abstract this - if strings.Contains(stats.Hostname, "www.google.") { + // TODO: Abstract this so we can add more groupings + if strings.Contains(hostname, "www.google.") { stats.Group = "Google" } } diff --git a/pkg/datastore/datastore.go b/pkg/datastore/datastore.go index b37ccb6..5d92933 100644 --- a/pkg/datastore/datastore.go +++ b/pkg/datastore/datastore.go @@ -45,17 +45,21 @@ type Datastore interface { DeletePageviews([]*models.Pageview) error // page stats - GetPageStats(int64, time.Time, string, string) (*models.PageStats, error) + GetPageStats(int64, time.Time, int64, int64) (*models.PageStats, error) SavePageStats(*models.PageStats) error GetAggregatedPageStats(int64, time.Time, time.Time, int64) ([]*models.PageStats, error) GetAggregatedPageStatsPageviews(int64, time.Time, time.Time) (int64, error) // referrer stats - GetReferrerStats(int64, time.Time, string, string) (*models.ReferrerStats, error) + GetReferrerStats(int64, time.Time, int64, int64) (*models.ReferrerStats, error) SaveReferrerStats(*models.ReferrerStats) error GetAggregatedReferrerStats(int64, time.Time, time.Time, int64) ([]*models.ReferrerStats, error) GetAggregatedReferrerStatsPageviews(int64, time.Time, time.Time) (int64, error) + // hostnames + HostnameID(name string) (int64, error) + PathnameID(name string) (int64, error) + // misc Health() error Close() error diff --git a/pkg/datastore/sqlstore/hostnames.go b/pkg/datastore/sqlstore/hostnames.go new file mode 100644 index 0000000..da47f5d --- /dev/null +++ b/pkg/datastore/sqlstore/hostnames.go @@ -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 +} diff --git a/pkg/datastore/sqlstore/migrations/mysql/12_create_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/mysql/12_create_hostnames_table.sql new file mode 100644 index 0000000..8a7bcd4 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/12_create_hostnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/mysql/13_create_unique_hostname_index.sql b/pkg/datastore/sqlstore/migrations/mysql/13_create_unique_hostname_index.sql new file mode 100644 index 0000000..a15cf66 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/13_create_unique_hostname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_hostnames_name; diff --git a/pkg/datastore/sqlstore/migrations/mysql/14_create_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/mysql/14_create_pathnames_table.sql new file mode 100644 index 0000000..2cebe40 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/14_create_pathnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/mysql/15_create_unique_pathname_index.sql b/pkg/datastore/sqlstore/migrations/mysql/15_create_unique_pathname_index.sql new file mode 100644 index 0000000..fdc8112 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/15_create_unique_pathname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_pathnames_name; diff --git a/pkg/datastore/sqlstore/migrations/mysql/16_fill_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/mysql/16_fill_hostnames_table.sql new file mode 100644 index 0000000..201f3e2 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/16_fill_hostnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/mysql/17_fill_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/mysql/17_fill_pathnames_table.sql new file mode 100644 index 0000000..903758d --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/17_fill_pathnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/mysql/18_alter_page_stats_table.sql b/pkg/datastore/sqlstore/migrations/mysql/18_alter_page_stats_table.sql new file mode 100644 index 0000000..547cf1e --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/18_alter_page_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/mysql/19_alter_referrer_stats_table.sql b/pkg/datastore/sqlstore/migrations/mysql/19_alter_referrer_stats_table.sql new file mode 100644 index 0000000..9f64760 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/19_alter_referrer_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/mysql/20_recreate_stats_indices.sql b/pkg/datastore/sqlstore/migrations/mysql/20_recreate_stats_indices.sql new file mode 100644 index 0000000..5f875c4 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/mysql/20_recreate_stats_indices.sql @@ -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; \ No newline at end of file diff --git a/pkg/datastore/sqlstore/migrations/postgres/13_create_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/postgres/13_create_hostnames_table.sql new file mode 100644 index 0000000..1df1675 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/13_create_hostnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/postgres/14_create_unique_hostname_index.sql b/pkg/datastore/sqlstore/migrations/postgres/14_create_unique_hostname_index.sql new file mode 100644 index 0000000..a15cf66 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/14_create_unique_hostname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_hostnames_name; diff --git a/pkg/datastore/sqlstore/migrations/postgres/15_create_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/postgres/15_create_pathnames_table.sql new file mode 100644 index 0000000..e8eabeb --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/15_create_pathnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/postgres/16_create_unique_pathname_index.sql b/pkg/datastore/sqlstore/migrations/postgres/16_create_unique_pathname_index.sql new file mode 100644 index 0000000..fdc8112 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/16_create_unique_pathname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_pathnames_name; diff --git a/pkg/datastore/sqlstore/migrations/postgres/17_fill_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/postgres/17_fill_hostnames_table.sql new file mode 100644 index 0000000..0421e5b --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/17_fill_hostnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/postgres/18_fill_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/postgres/18_fill_pathnames_table.sql new file mode 100644 index 0000000..52a8adf --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/18_fill_pathnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/postgres/19_alter_page_stats_table.sql b/pkg/datastore/sqlstore/migrations/postgres/19_alter_page_stats_table.sql new file mode 100644 index 0000000..6b38320 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/19_alter_page_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/postgres/20_alter_referrer_stats_table.sql b/pkg/datastore/sqlstore/migrations/postgres/20_alter_referrer_stats_table.sql new file mode 100644 index 0000000..716413e --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/20_alter_referrer_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/postgres/21_recreate_stats_indices.sql b/pkg/datastore/sqlstore/migrations/postgres/21_recreate_stats_indices.sql new file mode 100644 index 0000000..fabe2f3 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/postgres/21_recreate_stats_indices.sql @@ -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; \ No newline at end of file diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/12_create_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/12_create_hostnames_table.sql new file mode 100644 index 0000000..919dc15 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/12_create_hostnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/13_create_unique_hostname_index.sql b/pkg/datastore/sqlstore/migrations/sqlite3/13_create_unique_hostname_index.sql new file mode 100644 index 0000000..a15cf66 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/13_create_unique_hostname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_hostnames_name ON hostnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_hostnames_name; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/14_create_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/14_create_pathnames_table.sql new file mode 100644 index 0000000..b42aa7c --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/14_create_pathnames_table.sql @@ -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; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/15_create_unique_pathname_index.sql b/pkg/datastore/sqlstore/migrations/sqlite3/15_create_unique_pathname_index.sql new file mode 100644 index 0000000..fdc8112 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/15_create_unique_pathname_index.sql @@ -0,0 +1,5 @@ +-- +migrate Up +CREATE UNIQUE INDEX unique_pathnames_name ON pathnames(name); + +-- +migrate Down +DROP INDEX IF EXISTS unique_pathnames_name; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/16_fill_hostnames_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/16_fill_hostnames_table.sql new file mode 100644 index 0000000..502b04c --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/16_fill_hostnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/17_fill_pathnames_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/17_fill_pathnames_table.sql new file mode 100644 index 0000000..2f86852 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/17_fill_pathnames_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/18_alter_page_stats_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/18_alter_page_stats_table.sql new file mode 100644 index 0000000..6b38320 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/18_alter_page_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/19_alter_referrer_stats_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/19_alter_referrer_stats_table.sql new file mode 100644 index 0000000..07f1124 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/19_alter_referrer_stats_table.sql @@ -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 + diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/20_recreate_stats_indices.sql b/pkg/datastore/sqlstore/migrations/sqlite3/20_recreate_stats_indices.sql new file mode 100644 index 0000000..ad33a15 --- /dev/null +++ b/pkg/datastore/sqlstore/migrations/sqlite3/20_recreate_stats_indices.sql @@ -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; \ No newline at end of file diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/7_add_site_id_to_site_stats_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/7_add_site_id_to_site_stats_table.sql index e291424..fa6e78e 100644 --- a/pkg/datastore/sqlstore/migrations/sqlite3/7_add_site_id_to_site_stats_table.sql +++ b/pkg/datastore/sqlstore/migrations/sqlite3/7_add_site_id_to_site_stats_table.sql @@ -4,5 +4,4 @@ ALTER TABLE daily_site_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1; -- +migrate Down -ALTER TABLE daily_site_stats DROP COLUMN site_id; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/8_add_site_id_to_page_stats_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/8_add_site_id_to_page_stats_table.sql index e5aac52..f91d7a2 100644 --- a/pkg/datastore/sqlstore/migrations/sqlite3/8_add_site_id_to_page_stats_table.sql +++ b/pkg/datastore/sqlstore/migrations/sqlite3/8_add_site_id_to_page_stats_table.sql @@ -4,5 +4,4 @@ ALTER TABLE daily_page_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1; -- +migrate Down -ALTER TABLE daily_page_stats DROP COLUMN site_id; diff --git a/pkg/datastore/sqlstore/migrations/sqlite3/9_add_site_id_to_referrer_stats_table.sql b/pkg/datastore/sqlstore/migrations/sqlite3/9_add_site_id_to_referrer_stats_table.sql index 192afe1..3d02446 100644 --- a/pkg/datastore/sqlstore/migrations/sqlite3/9_add_site_id_to_referrer_stats_table.sql +++ b/pkg/datastore/sqlstore/migrations/sqlite3/9_add_site_id_to_referrer_stats_table.sql @@ -4,5 +4,4 @@ ALTER TABLE daily_referrer_stats ADD COLUMN site_id INTEGER NOT NULL DEFAULT 1; -- +migrate Down -ALTER TABLE daily_referrer_stats DROP COLUMN site_id; diff --git a/pkg/datastore/sqlstore/page_stats.go b/pkg/datastore/sqlstore/page_stats.go index f58c986..723b3e8 100644 --- a/pkg/datastore/sqlstore/page_stats.go +++ b/pkg/datastore/sqlstore/page_stats.go @@ -7,10 +7,10 @@ import ( "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} - query := db.Rebind(`SELECT * FROM daily_page_stats WHERE site_id = ? AND hostname = ? AND pathname = ? AND date = ? LIMIT 1`) - err := db.Get(stats, query, siteID, hostname, pathname, date.Format("2006-01-02")) + 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, hostnameID, pathnameID, date.Format("2006-01-02")) if err == sql.ErrNoRows { return nil, ErrNoResults } @@ -27,28 +27,31 @@ func (db *sqlstore) SavePageStats(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(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`) - _, 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")) + 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.HostnameID, s.PathnameID, s.Date.Format("2006-01-02")) return err } 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 = ?`) - _, 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")) + 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.HostnameID, s.PathnameID, s.Date.Format("2006-01-02")) return err } func (db *sqlstore) GetAggregatedPageStats(siteID int64, startDate time.Time, endDate time.Time, limit int64) ([]*models.PageStats, error) { var result []*models.PageStats query := db.Rebind(`SELECT - hostname, - pathname, + h.name AS hostname, + p.name AS pathname, SUM(pageviews) AS pageviews, SUM(visitors) AS visitors, SUM(entries) AS entries, 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 - FROM daily_page_stats WHERE site_id = ? AND date >= ? AND date <= ? + COALESCE(SUM(pageviews*avg_duration) / SUM(pageviews), 0.00) AS avg_duration + 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 ORDER BY pageviews DESC LIMIT ?`) err := db.Select(&result, query, siteID, startDate.Format("2006-01-02"), endDate.Format("2006-01-02"), limit) diff --git a/pkg/datastore/sqlstore/pathnames.go b/pkg/datastore/sqlstore/pathnames.go new file mode 100644 index 0000000..536c396 --- /dev/null +++ b/pkg/datastore/sqlstore/pathnames.go @@ -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 +} diff --git a/pkg/datastore/sqlstore/referrer_stats.go b/pkg/datastore/sqlstore/referrer_stats.go index 5f820b7..e2d395d 100644 --- a/pkg/datastore/sqlstore/referrer_stats.go +++ b/pkg/datastore/sqlstore/referrer_stats.go @@ -7,10 +7,10 @@ import ( "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} - query := db.Rebind(`SELECT * FROM daily_referrer_stats WHERE site_id = ? AND date = ? AND hostname = ? AND pathname = ? LIMIT 1`) - err := db.Get(stats, query, siteID, date.Format("2006-01-02"), hostname, pathname) + 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"), hostnameID, pathnameID) if err == sql.ErrNoRows { return nil, ErrNoResults } @@ -27,14 +27,14 @@ func (db *sqlstore) SaveReferrerStats(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(?, ?, ?, ?, ?, ?, ?, ?, ?, ?)`) - _, 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")) + 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.HostnameID, s.PathnameID, s.Date.Format("2006-01-02")) return err } 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 = ?`) - _, 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")) + 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.HostnameID, s.PathnameID, s.Date.Format("2006-01-02")) return err } @@ -42,14 +42,16 @@ func (db *sqlstore) GetAggregatedReferrerStats(siteID int64, startDate time.Time var result []*models.ReferrerStats sql := `SELECT - MIN(hostname) AS hostname, - MIN(pathname) AS pathname, - COALESCE(MIN(groupname), '') AS groupname, + h.name AS hostname, + p.name AS pathname, + COALESCE(groupname, '') AS groupname, SUM(visitors) AS visitors, SUM(pageviews) AS pageviews, 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 - FROM daily_referrer_stats + COALESCE(SUM(pageviews*avg_duration) / SUM(pageviews), 0.00) AS avg_duration + 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 <= ? ` if db.Config.Driver == "sqlite3" { diff --git a/pkg/models/page_stats.go b/pkg/models/page_stats.go index 3a9d042..01bd57a 100644 --- a/pkg/models/page_stats.go +++ b/pkg/models/page_stats.go @@ -7,6 +7,8 @@ import ( type PageStats struct { New bool `db:"-" json:"-"` SiteID int64 `db:"site_id"` + HostnameID int64 `db:"hostname_id" json:"-"` + PathnameID int64 `db:"pathname_id" json:"-"` Hostname string `db:"hostname"` Pathname string `db:"pathname"` Pageviews int64 `db:"pageviews"` diff --git a/pkg/models/referrer_stats.go b/pkg/models/referrer_stats.go index 1586d22..b2cea0d 100644 --- a/pkg/models/referrer_stats.go +++ b/pkg/models/referrer_stats.go @@ -7,6 +7,8 @@ import ( type ReferrerStats struct { New bool `db:"-" json:"-"` SiteID int64 `db:"site_id"` + HostnameID int64 `db:"hostname_id" json:"-"` + PathnameID int64 `db:"pathname_id" json:"-"` Hostname string `db:"hostname"` Pathname string `db:"pathname"` Group string `db:"groupname"`