optimize stats using "materialized view"
This commit is contained in:
parent
1e291882a6
commit
be3023f55d
@ -1,2 +1,3 @@
|
||||
.env
|
||||
**/__pycache__
|
||||
**/*.db*
|
||||
|
@ -1,6 +1,6 @@
|
||||
FROM python:3.13-alpine
|
||||
|
||||
RUN apk add --no-cache s6 bash wget unzip curl
|
||||
RUN apk add --no-cache s6 bash wget unzip curl sqlite
|
||||
|
||||
COPY requirements.txt .
|
||||
|
||||
|
2
cmd.txt
2
cmd.txt
@ -1,6 +1,6 @@
|
||||
. .venv/bin/activate
|
||||
|
||||
export VERSION=0.1.0
|
||||
export VERSION=0.2.0
|
||||
|
||||
docker build -t mobilizon-instances:${VERSION} .
|
||||
|
||||
|
5
scripts/refresh_day_stats.sh
Executable file
5
scripts/refresh_day_stats.sh
Executable file
@ -0,0 +1,5 @@
|
||||
#!/bin/bash -eu
|
||||
|
||||
CMDD=$(dirname $(realpath $0))
|
||||
|
||||
sqlite3 ${SQLPAGE_DATABASE_URL:9} < ${CMDD}/../sqlpage/migrations/003_create_daystats.sql
|
@ -1,12 +1,4 @@
|
||||
-- set some pragma
|
||||
PRAGMA journal_mode = WAL;
|
||||
PRAGMA busy_timeout = 15000; -- for interactive, 15s for background tasks
|
||||
PRAGMA synchronous = NORMAL;
|
||||
PRAGMA cache_size = 1000000000; -- means infinite
|
||||
PRAGMA foreign_keys = true;
|
||||
PRAGMA temp_store = memory;
|
||||
|
||||
CREATE TABLE instances (
|
||||
CREATE TABLE if not exists instances (
|
||||
-- PK will be rowid
|
||||
domain TEXT UNIQUE
|
||||
, name TEXT
|
||||
@ -21,7 +13,7 @@ CREATE TABLE instances (
|
||||
, updatedAt INTEGER -- second since epoch
|
||||
) strict;
|
||||
|
||||
create table stats (
|
||||
create table if not exists stats (
|
||||
insertedAt INTEGER
|
||||
, instance_id INTEGER -- rowid of instance
|
||||
, users INTEGER
|
2
sqlpage/migrations/002_index_stats.sql
Normal file
2
sqlpage/migrations/002_index_stats.sql
Normal file
@ -0,0 +1,2 @@
|
||||
CREATE INDEX if not exists idx_stats_day ON stats(insertedAt / (3600*24));
|
||||
|
12
sqlpage/migrations/003_create_daystats.sql
Normal file
12
sqlpage/migrations/003_create_daystats.sql
Normal file
@ -0,0 +1,12 @@
|
||||
DROP table if exists day_stats;
|
||||
|
||||
Create table day_stats as
|
||||
SELECT
|
||||
count(instance_id) as i
|
||||
, sum(users) as u
|
||||
, sum(local_events) as e
|
||||
, sum(local_groups) as g
|
||||
, insertedAt as x
|
||||
, insertedAt / (3600*24) as j
|
||||
FROM stats
|
||||
GROUP BY j
|
@ -19,32 +19,17 @@ select
|
||||
-- total Users
|
||||
select
|
||||
'Users' as title
|
||||
, (select sum(users) from ( SELECT
|
||||
instance_id,
|
||||
users,
|
||||
MAX(insertedAt)
|
||||
FROM stats
|
||||
GROUP BY instance_id)) as value
|
||||
, (SELECT u FROM day_stats order by j desc limit 1) as value
|
||||
;
|
||||
-- total Groups
|
||||
select
|
||||
'Groups' as title
|
||||
, (select sum(local_groups) from ( SELECT
|
||||
instance_id,
|
||||
local_groups,
|
||||
MAX(insertedAt)
|
||||
FROM stats
|
||||
GROUP BY instance_id)) as value
|
||||
, (SELECT g FROM day_stats order by j desc limit 1) as value
|
||||
;
|
||||
-- total Events
|
||||
select
|
||||
'Events' as title
|
||||
, (select sum(local_events) from ( SELECT
|
||||
instance_id,
|
||||
local_events,
|
||||
MAX(insertedAt)
|
||||
FROM stats
|
||||
GROUP BY instance_id)) as value
|
||||
, (SELECT e FROM day_stats order by j desc limit 1) as value
|
||||
;
|
||||
|
||||
----- over time ----
|
||||
@ -62,13 +47,7 @@ select
|
||||
--, 5 as marker
|
||||
, TRUE as time
|
||||
;
|
||||
SELECT
|
||||
count(instance_id) as y
|
||||
, insertedAt as x
|
||||
, insertedAt / (3600*24) as j
|
||||
FROM stats
|
||||
GROUP BY j
|
||||
order by j
|
||||
SELECT i as y, x FROM day_stats
|
||||
;
|
||||
-- users
|
||||
select
|
||||
@ -79,13 +58,7 @@ select
|
||||
--, 5 as marker
|
||||
, TRUE as time
|
||||
;
|
||||
SELECT
|
||||
sum(users) as y
|
||||
, insertedAt as x
|
||||
, insertedAt / (3600*24) as j
|
||||
FROM stats
|
||||
GROUP BY j
|
||||
order by j
|
||||
SELECT u as y, x FROM day_stats
|
||||
;
|
||||
-- events
|
||||
select
|
||||
@ -96,13 +69,7 @@ select
|
||||
--, 5 as marker
|
||||
, TRUE as time
|
||||
;
|
||||
SELECT
|
||||
sum(local_events) as y
|
||||
, insertedAt as x
|
||||
, insertedAt / (3600*24) as j
|
||||
FROM stats
|
||||
GROUP BY j
|
||||
order by j
|
||||
SELECT e as y, x FROM day_stats
|
||||
;
|
||||
-- groups
|
||||
select
|
||||
@ -113,11 +80,5 @@ select
|
||||
--, 5 as marker
|
||||
, TRUE as time
|
||||
;
|
||||
SELECT
|
||||
sum(local_groups) as y
|
||||
, insertedAt as x
|
||||
, insertedAt / (3600*24) as j
|
||||
FROM stats
|
||||
GROUP BY j
|
||||
order by j
|
||||
SELECT g as y, x FROM day_stats
|
||||
;
|
||||
|
Loading…
x
Reference in New Issue
Block a user