mirror of
https://github.com/status-im/fathom.git
synced 2025-02-28 19:10:36 +00:00
introduced table to x1000 UI performance when working with big datasets
This commit is contained in:
parent
7d7121cf14
commit
f25c18a7fe
1
.gitignore
vendored
1
.gitignore
vendored
@ -2,3 +2,4 @@ node_modules
|
|||||||
static
|
static
|
||||||
.env
|
.env
|
||||||
storage
|
storage
|
||||||
|
ana
|
||||||
|
11
ROADMAP.md
11
ROADMAP.md
@ -5,11 +5,14 @@ This is a general draft document for thoughts and todo's, without any structure
|
|||||||
|
|
||||||
### What's cooking?
|
### What's cooking?
|
||||||
|
|
||||||
|
- Archive `pageviews` table into daily totals for performance
|
||||||
|
- Create archive on-the-fly if it does not exist yet
|
||||||
|
- Bulk process tracking requests (Redis or in-memory?)
|
||||||
|
- Allow for multiple sites in same instance
|
||||||
- Update page title when it changes.
|
- Update page title when it changes.
|
||||||
- Custom date range picker
|
- Custom date range picker
|
||||||
- Bulk process tracking requests (Redis or in-memory?)
|
- Choose a better name than "Ana"
|
||||||
- Allow sorting in table overviews.
|
- Envelope API responses
|
||||||
- Choose a OS license & settle on name.
|
- Visual error handling on client-side.
|
||||||
- Envelope API responses & perhaps return total in table overview?
|
|
||||||
- Geolocate IP addresses periodically.
|
- Geolocate IP addresses periodically.
|
||||||
- Mask last part of IP address.
|
- Mask last part of IP address.
|
||||||
|
@ -49,7 +49,11 @@ var GetPageviewsHandler = http.HandlerFunc(func(w http.ResponseWriter, r *http.R
|
|||||||
// URL: /api/pageviews/count
|
// URL: /api/pageviews/count
|
||||||
var GetPageviewsCountHandler = http.HandlerFunc(func(w http.ResponseWriter, r *http.Request) {
|
var GetPageviewsCountHandler = http.HandlerFunc(func(w http.ResponseWriter, r *http.Request) {
|
||||||
before, after := getRequestedPeriods(r)
|
before, after := getRequestedPeriods(r)
|
||||||
stmt, err := db.Conn.Prepare(`SELECT COUNT(*) FROM pageviews pv WHERE UNIX_TIMESTAMP(pv.timestamp) <= ? AND UNIX_TIMESTAMP(pv.timestamp) >= ?`)
|
stmt, err := db.Conn.Prepare(`
|
||||||
|
SELECT
|
||||||
|
SUM(a.count) AS count
|
||||||
|
FROM archive a
|
||||||
|
WHERE a.metric = 'pageviews' AND UNIX_TIMESTAMP(a.date) <= ? AND UNIX_TIMESTAMP(a.date) >= ?`)
|
||||||
checkError(err)
|
checkError(err)
|
||||||
defer stmt.Close()
|
defer stmt.Close()
|
||||||
|
|
||||||
@ -70,9 +74,10 @@ var GetPageviewsPeriodCountHandler = http.HandlerFunc(func(w http.ResponseWriter
|
|||||||
}
|
}
|
||||||
before, after := getRequestedPeriods(r)
|
before, after := getRequestedPeriods(r)
|
||||||
stmt, err := db.Conn.Prepare(`SELECT
|
stmt, err := db.Conn.Prepare(`SELECT
|
||||||
COUNT(*) AS count, DATE_FORMAT(timestamp, ?) AS date_group
|
SUM(a.count) AS count,
|
||||||
FROM pageviews pv
|
DATE_FORMAT(a.date, ?) AS date_group
|
||||||
WHERE UNIX_TIMESTAMP(pv.timestamp) <= ? AND UNIX_TIMESTAMP(pv.timestamp) >= ?
|
FROM archive a
|
||||||
|
WHERE a.metric = 'pageviews' AND UNIX_TIMESTAMP(a.date) <= ? AND UNIX_TIMESTAMP(a.date) >= ?
|
||||||
GROUP BY date_group`)
|
GROUP BY date_group`)
|
||||||
checkError(err)
|
checkError(err)
|
||||||
defer stmt.Close()
|
defer stmt.Close()
|
||||||
|
@ -11,7 +11,12 @@ import (
|
|||||||
// URL: /api/visitors/count
|
// URL: /api/visitors/count
|
||||||
var GetVisitorsCountHandler = http.HandlerFunc(func(w http.ResponseWriter, r *http.Request) {
|
var GetVisitorsCountHandler = http.HandlerFunc(func(w http.ResponseWriter, r *http.Request) {
|
||||||
before, after := getRequestedPeriods(r)
|
before, after := getRequestedPeriods(r)
|
||||||
stmt, err := db.Conn.Prepare(`SELECT COUNT(DISTINCT(visitor_id)) FROM pageviews WHERE UNIX_TIMESTAMP(timestamp) <= ? AND UNIX_TIMESTAMP(timestamp) >= ?`)
|
stmt, err := db.Conn.Prepare(`
|
||||||
|
SELECT
|
||||||
|
SUM(a.count)
|
||||||
|
FROM archive a
|
||||||
|
WHERE a.metric = 'visitors' AND UNIX_TIMESTAMP(a.date) <= ? AND UNIX_TIMESTAMP(a.date) >= ?
|
||||||
|
`)
|
||||||
|
|
||||||
checkError(err)
|
checkError(err)
|
||||||
defer stmt.Close()
|
defer stmt.Close()
|
||||||
@ -43,9 +48,10 @@ var GetVisitorsPeriodCountHandler = http.HandlerFunc(func(w http.ResponseWriter,
|
|||||||
}
|
}
|
||||||
|
|
||||||
stmt, err := db.Conn.Prepare(`SELECT
|
stmt, err := db.Conn.Prepare(`SELECT
|
||||||
COUNT(DISTINCT(visitor_id)) AS count, DATE_FORMAT(timestamp, ?) AS date_group
|
SUM(a.count) AS count,
|
||||||
FROM pageviews pv
|
DATE_FORMAT(a.date, ?) AS date_group
|
||||||
WHERE UNIX_TIMESTAMP(pv.timestamp) <= ? AND UNIX_TIMESTAMP(pv.timestamp) >= ?
|
FROM archive a
|
||||||
|
WHERE a.metric = 'visitors' AND UNIX_TIMESTAMP(a.date) <= ? AND UNIX_TIMESTAMP(a.date) >= ?
|
||||||
GROUP BY date_group`)
|
GROUP BY date_group`)
|
||||||
checkError(err)
|
checkError(err)
|
||||||
defer stmt.Close()
|
defer stmt.Close()
|
||||||
|
@ -148,7 +148,9 @@ class Graph extends Component {
|
|||||||
}
|
}
|
||||||
|
|
||||||
refreshChart() {
|
refreshChart() {
|
||||||
|
|
||||||
if(this.data.visitors && this.data.pageviews) {
|
if(this.data.visitors && this.data.pageviews) {
|
||||||
|
this.loadingIndicator.style.display = 'none';
|
||||||
this.chart.setData(this.data.pageviews, this.data.visitors)
|
this.chart.setData(this.data.pageviews, this.data.visitors)
|
||||||
this.chart.draw()
|
this.chart.draw()
|
||||||
}
|
}
|
||||||
@ -158,6 +160,7 @@ class Graph extends Component {
|
|||||||
const before = Math.round((+new Date() ) / 1000);
|
const before = Math.round((+new Date() ) / 1000);
|
||||||
const after = before - ( period * dayInSeconds );
|
const after = before - ( period * dayInSeconds );
|
||||||
const group = period > 90 ? 'month' : 'day';
|
const group = period > 90 ? 'month' : 'day';
|
||||||
|
this.loadingIndicator.style.display = '';
|
||||||
|
|
||||||
Client
|
Client
|
||||||
.request(`pageviews/count/group/${group}?before=${before}&after=${after}`)
|
.request(`pageviews/count/group/${group}?before=${before}&after=${after}`)
|
||||||
@ -176,7 +179,10 @@ class Graph extends Component {
|
|||||||
|
|
||||||
render() {
|
render() {
|
||||||
return (
|
return (
|
||||||
|
<div>
|
||||||
|
<div class="loading-overlay" ref={(el) => { this.loadingIndicator = el }}><div></div></div>
|
||||||
<div id="graph"></div>
|
<div id="graph"></div>
|
||||||
|
</div>
|
||||||
)
|
)
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
@ -7,7 +7,8 @@ import(
|
|||||||
var runCreateUserCommand bool
|
var runCreateUserCommand bool
|
||||||
var runDeleteUserCommand bool
|
var runDeleteUserCommand bool
|
||||||
var runStartServerCommand bool
|
var runStartServerCommand bool
|
||||||
var runSeedDatabaseCommand bool
|
var runSeedDataCommand bool
|
||||||
|
var runArchiveDataCommand bool
|
||||||
var idArg int
|
var idArg int
|
||||||
var emailArg string
|
var emailArg string
|
||||||
var passwordArg string
|
var passwordArg string
|
||||||
@ -18,7 +19,8 @@ func Parse() {
|
|||||||
flag.BoolVar(&runCreateUserCommand, "create_user", false, "Create a new user")
|
flag.BoolVar(&runCreateUserCommand, "create_user", false, "Create a new user")
|
||||||
flag.BoolVar(&runDeleteUserCommand, "delete_user", false, "Deletes a user")
|
flag.BoolVar(&runDeleteUserCommand, "delete_user", false, "Deletes a user")
|
||||||
flag.BoolVar(&runStartServerCommand, "start_server", true, "Start the API web server")
|
flag.BoolVar(&runStartServerCommand, "start_server", true, "Start the API web server")
|
||||||
flag.BoolVar(&runSeedDatabaseCommand, "seed_database", false, "Seed the database -n times")
|
flag.BoolVar(&runSeedDataCommand, "seed_data", false, "Seed the database -n times")
|
||||||
|
flag.BoolVar(&runArchiveDataCommand, "archive_data", false, "Archives data into daily aggregated totals")
|
||||||
flag.StringVar(&emailArg, "email", "", "Email address")
|
flag.StringVar(&emailArg, "email", "", "Email address")
|
||||||
flag.StringVar(&passwordArg, "password", "", "Password")
|
flag.StringVar(&passwordArg, "password", "", "Password")
|
||||||
flag.IntVar(&idArg, "id", 0, "Object ID")
|
flag.IntVar(&idArg, "id", 0, "Object ID")
|
||||||
@ -31,8 +33,10 @@ func Run() {
|
|||||||
createUser()
|
createUser()
|
||||||
} else if runDeleteUserCommand {
|
} else if runDeleteUserCommand {
|
||||||
deleteUser()
|
deleteUser()
|
||||||
} else if runSeedDatabaseCommand {
|
} else if runSeedDataCommand {
|
||||||
seedDatabase()
|
seedData()
|
||||||
|
} else if runArchiveDataCommand {
|
||||||
|
archiveData()
|
||||||
} else if runStartServerCommand {
|
} else if runStartServerCommand {
|
||||||
startServer()
|
startServer()
|
||||||
}
|
}
|
||||||
|
@ -4,6 +4,10 @@ import(
|
|||||||
"github.com/dannyvankooten/ana/db"
|
"github.com/dannyvankooten/ana/db"
|
||||||
)
|
)
|
||||||
|
|
||||||
func seedDatabase() {
|
func seedData() {
|
||||||
db.Seed(nArg)
|
db.Seed(nArg)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
func archiveData() {
|
||||||
|
db.CreateArchives()
|
||||||
|
}
|
122
db/archive.go
Normal file
122
db/archive.go
Normal file
@ -0,0 +1,122 @@
|
|||||||
|
package db
|
||||||
|
|
||||||
|
import(
|
||||||
|
"database/sql"
|
||||||
|
"log"
|
||||||
|
)
|
||||||
|
|
||||||
|
|
||||||
|
type Archive struct {
|
||||||
|
ID int64
|
||||||
|
Metric string
|
||||||
|
Value string
|
||||||
|
Count int64
|
||||||
|
Date string
|
||||||
|
}
|
||||||
|
|
||||||
|
func (a *Archive) Save(conn *sql.DB) error {
|
||||||
|
stmt, err := conn.Prepare(`INSERT INTO archive(
|
||||||
|
metric,
|
||||||
|
value,
|
||||||
|
count,
|
||||||
|
date
|
||||||
|
) VALUES( ?, ?, ?, ? )`)
|
||||||
|
if err != nil {
|
||||||
|
return err
|
||||||
|
}
|
||||||
|
defer stmt.Close()
|
||||||
|
|
||||||
|
result, err := stmt.Exec(
|
||||||
|
a.Metric,
|
||||||
|
a.Value,
|
||||||
|
a.Count,
|
||||||
|
a.Date,
|
||||||
|
)
|
||||||
|
a.ID, _ = result.LastInsertId()
|
||||||
|
|
||||||
|
return err
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
|
func CreateArchives() {
|
||||||
|
CreatePageviewArchives()
|
||||||
|
CreateVisitorArchives()
|
||||||
|
}
|
||||||
|
|
||||||
|
func CreatePageviewArchives() {
|
||||||
|
stmt, err := Conn.Prepare(`
|
||||||
|
SELECT
|
||||||
|
COUNT(*) AS count,
|
||||||
|
DATE_FORMAT(pv.timestamp, "%Y-%m-%d") AS date_group
|
||||||
|
FROM pageviews pv
|
||||||
|
WHERE NOT EXISTS(
|
||||||
|
SELECT a.id
|
||||||
|
FROM archive a
|
||||||
|
WHERE a.metric = 'pageviews' AND a.date = DATE_FORMAT(pv.timestamp, "%Y-%m-%d")
|
||||||
|
)
|
||||||
|
GROUP BY date_group`)
|
||||||
|
checkError(err)
|
||||||
|
defer stmt.Close()
|
||||||
|
|
||||||
|
rows, err := stmt.Query()
|
||||||
|
checkError(err)
|
||||||
|
defer rows.Close()
|
||||||
|
|
||||||
|
Conn.Exec("START TRANSACTION")
|
||||||
|
for rows.Next() {
|
||||||
|
a := Archive{
|
||||||
|
Metric: "pageviews",
|
||||||
|
Value: "",
|
||||||
|
}
|
||||||
|
err = rows.Scan(&a.Count, &a.Date);
|
||||||
|
checkError(err)
|
||||||
|
a.Save(Conn)
|
||||||
|
}
|
||||||
|
Conn.Exec("COMMIT")
|
||||||
|
}
|
||||||
|
|
||||||
|
func CreateVisitorArchives() {
|
||||||
|
|
||||||
|
/*
|
||||||
|
SELECT
|
||||||
|
COUNT(DISTINCT(visitor_id)) AS count, DATE_FORMAT(timestamp, ?) AS date_group
|
||||||
|
FROM pageviews pv
|
||||||
|
WHERE UNIX_TIMESTAMP(pv.timestamp) <= ? AND UNIX_TIMESTAMP(pv.timestamp) >= ?
|
||||||
|
GROUP BY date_group
|
||||||
|
*/
|
||||||
|
stmt, err := Conn.Prepare(`
|
||||||
|
SELECT
|
||||||
|
COUNT(DISTINCT(pv.visitor_id)) AS count,
|
||||||
|
DATE_FORMAT(pv.timestamp, "%Y-%m-%d") AS date_group
|
||||||
|
FROM pageviews pv
|
||||||
|
WHERE NOT EXISTS(
|
||||||
|
SELECT a.id
|
||||||
|
FROM archive a
|
||||||
|
WHERE a.metric = 'visitors' AND a.date = DATE_FORMAT(pv.timestamp, "%Y-%m-%d")
|
||||||
|
)
|
||||||
|
GROUP BY date_group`)
|
||||||
|
checkError(err)
|
||||||
|
defer stmt.Close()
|
||||||
|
|
||||||
|
rows, err := stmt.Query()
|
||||||
|
checkError(err)
|
||||||
|
defer rows.Close()
|
||||||
|
|
||||||
|
Conn.Exec("START TRANSACTION")
|
||||||
|
for rows.Next() {
|
||||||
|
a := Archive{
|
||||||
|
Metric: "visitors",
|
||||||
|
Value: "",
|
||||||
|
}
|
||||||
|
err = rows.Scan(&a.Count, &a.Date);
|
||||||
|
checkError(err)
|
||||||
|
a.Save(Conn)
|
||||||
|
}
|
||||||
|
Conn.Exec("COMMIT")
|
||||||
|
}
|
||||||
|
|
||||||
|
func checkError(err error) {
|
||||||
|
if err != nil {
|
||||||
|
log.Fatal(err)
|
||||||
|
}
|
||||||
|
}
|
@ -3,3 +3,4 @@ DROP TABLE if exists visitors;
|
|||||||
DROP TABLE IF EXISTS pages;
|
DROP TABLE IF EXISTS pages;
|
||||||
DROP TABLE IF EXISTS sites;
|
DROP TABLE IF EXISTS sites;
|
||||||
DROP TABLE IF EXISTS users;
|
DROP TABLE IF EXISTS users;
|
||||||
|
DROP TABLE IF EXISTS archive;
|
||||||
|
@ -1,6 +1,6 @@
|
|||||||
|
|
||||||
CREATE TABLE visitors(
|
CREATE TABLE visitors(
|
||||||
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY,
|
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY NOT NULL,
|
||||||
`visitor_key` VARCHAR(255) NOT NULL,
|
`visitor_key` VARCHAR(255) NOT NULL,
|
||||||
`ip_address` VARCHAR(100) NOT NULL,
|
`ip_address` VARCHAR(100) NOT NULL,
|
||||||
`device_os` VARCHAR(31) NULL,
|
`device_os` VARCHAR(31) NULL,
|
||||||
@ -10,20 +10,19 @@ CREATE TABLE visitors(
|
|||||||
`screen_resolution` VARCHAR(9) NULL,
|
`screen_resolution` VARCHAR(9) NULL,
|
||||||
`country` CHAR(3) NULL
|
`country` CHAR(3) NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE visitors ADD UNIQUE(`visitor_key`);
|
ALTER TABLE visitors ADD UNIQUE(`visitor_key`);
|
||||||
|
|
||||||
CREATE TABLE pageviews(
|
CREATE TABLE pageviews(
|
||||||
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY,
|
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY NOT NULL,
|
||||||
`page_id` INTEGER UNSIGNED NOT NULL,
|
`page_id` INTEGER UNSIGNED NOT NULL,
|
||||||
`visitor_id` INTEGER UNSIGNED NOT NULL,
|
`visitor_id` INTEGER UNSIGNED NOT NULL,
|
||||||
`referrer_keyword` TEXT NULL,
|
`referrer_keyword` TEXT NULL,
|
||||||
`referrer_url` TEXT NULL,
|
`referrer_url` TEXT NULL,
|
||||||
`timestamp` TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
`timestamp` TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||||
);
|
);
|
||||||
|
|
||||||
ALTER TABLE pageviews ADD FOREIGN KEY(`visitor_id`) REFERENCES visitors(`id`);
|
ALTER TABLE pageviews ADD FOREIGN KEY(`visitor_id`) REFERENCES visitors(`id`);
|
||||||
CREATE INDEX pageview_timestamp ON pageviews(timestamp(11));
|
ALTER TABLE pageviews ADD FOREIGN KEY(`page_id`) REFERENCES pages(`id`);
|
||||||
|
|
||||||
|
|
||||||
CREATE TABLE pages(
|
CREATE TABLE pages(
|
||||||
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY NOT NULL,
|
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY NOT NULL,
|
||||||
@ -37,3 +36,15 @@ CREATE TABLE users (
|
|||||||
`email` VARCHAR(255) NOT NULL,
|
`email` VARCHAR(255) NOT NULL,
|
||||||
`password` VARCHAR(255) NOT NULL
|
`password` VARCHAR(255) NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
|
CREATE TABLE `archive` (
|
||||||
|
`id` INTEGER UNSIGNED AUTO_INCREMENT PRIMARY KEY NOT NULL,
|
||||||
|
`metric` VARCHAR(31) NOT NULL,
|
||||||
|
`value` VARCHAR(31) NULL,
|
||||||
|
`count` INTEGER UNSIGNED NOT NULL,
|
||||||
|
`date` DATE NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX archive_metric ON archive(`metric`);
|
||||||
|
CREATE INDEX archive_metric_count ON archive(`metric`, `count`);
|
||||||
|
CREATE INDEX archive_metric_date ON archive(`metric`, `date`);
|
||||||
|
Loading…
x
Reference in New Issue
Block a user