Skip to content

Commit

Permalink
SQLite schema extensions and script for processing radacct: Data usag…
Browse files Browse the repository at this point in the history
…e per period (#3265)

Provides a table, indexes and SP for extracting per-user data usage within
arbitrary periods using the standard radacct table entries.
  • Loading branch information
terryburton authored and arr2036 committed Jan 18, 2020
1 parent c831fd6 commit 0252e1e
Show file tree
Hide file tree
Showing 2 changed files with 163 additions and 0 deletions.
112 changes: 112 additions & 0 deletions raddb/mods-config/sql/main/sqlite/process-radacct-refresh.sh
@@ -0,0 +1,112 @@
#!/bin/sh
#
# main/sqlite/process-radacct-refresh.sh -- Schema extensions and script for processing radacct entries
#
# $Id$

#
# See process-radacct-schema.sql for details.
#

if [ "$#" -ne 1 ]; then
echo "Usage: process-radacct-refresh.sh SQLITE_DB_FILE" 2>&1
exit 1
fi

if [ ! -r "$1" ]; then
echo "The SQLite database must exist: $1" 1>&2
exit 1
fi

cat <<EOF | sqlite3 "$1"
--
-- SQLite doesn't have a concept of session variables so we fake it.
--
DROP TABLE IF EXISTS vars;
CREATE TEMPORARY TABLE vars (
key text,
value text,
PRIMARY KEY (key)
);
INSERT INTO vars SELECT 'v_start', COALESCE(MAX(period_start), DATETIME(0, 'unixepoch')) FROM data_usage_by_period;
INSERT INTO vars SELECT 'v_end', CURRENT_TIMESTAMP;
--
-- Make of copy of the sessions that were active during this period to
-- avoid having to execute a potentially long transaction that might hold a
-- global database lock.
--
DROP TABLE IF EXISTS radacct_sessions;
CREATE TEMPORARY TABLE radacct_sessions (
username text,
acctstarttime datetime,
acctstoptime datetime,
acctinputoctets bigint,
acctoutputoctets bigint
);
CREATE INDEX temp.idx_radacct_sessions_username ON radacct_sessions(username);
CREATE INDEX temp.idx_radacct_sessions_acctstoptime ON radacct_sessions(acctstoptime);
INSERT INTO radacct_sessions
SELECT
username,
acctstarttime,
acctstoptime,
acctinputoctets,
acctoutputoctets
FROM
radacct
WHERE
acctstoptime > (SELECT value FROM vars WHERE key='v_start') OR
acctstoptime IS NULL;
--
-- Add the data usage for the sessions that were active in the current
-- period to the table. Include all sessions that finished since the start
-- of this period as well as those still ongoing.
--
INSERT INTO data_usage_by_period (username, period_start, period_end, acctinputoctets, acctoutputoctets)
SELECT
username,
(SELECT value FROM vars WHERE key='v_start'),
(SELECT value FROM vars WHERE key='v_end'),
SUM(acctinputoctets) AS acctinputoctets,
SUM(acctoutputoctets) AS acctoutputoctets
FROM
radacct_sessions
GROUP BY
username
ON CONFLICT(username,period_start) DO UPDATE
SET
acctinputoctets = data_usage_by_period.acctinputoctets + EXCLUDED.acctinputoctets,
acctoutputoctets = data_usage_by_period.acctoutputoctets + EXCLUDED.acctoutputoctets,
period_end = (SELECT value FROM vars WHERE key='v_end');
--
-- Create an open-ended "next period" for all ongoing sessions and carry a
-- negative value of their data usage to avoid double-accounting when we
-- process the next period. Their current data usage has already been
-- allocated to the current and possibly previous periods.
--
INSERT INTO data_usage_by_period (username, period_start, period_end, acctinputoctets, acctoutputoctets)
SELECT
username,
(SELECT DATETIME(value, '+1 seconds') FROM vars WHERE key='v_end'),
NULL,
0 - SUM(acctinputoctets),
0 - SUM(acctoutputoctets)
FROM
radacct_sessions
WHERE
acctstoptime IS NULL
GROUP BY
username;
DROP TABLE vars;
DROP TABLE radacct_sessions;
EOF
51 changes: 51 additions & 0 deletions raddb/mods-config/sql/main/sqlite/process-radacct-schema.sql
@@ -0,0 +1,51 @@
# -*- text -*-
#
# main/sqlite/process-radacct.sql -- Schema extensions and script for processing radacct entries
#
# $Id$

-- ---------------------------------
-- - Per-user data usage over time -
-- ---------------------------------
--
-- An extension to the standard schema to hold per-user data usage statistics
-- for arbitrary periods.
--
-- The data_usage_by_period table is populated by periodically calling the
-- process-radacct-refresh.sh script.
--
-- This table can be queried in various ways to produce reports of aggregate
-- data use over time. For example, if the refresh script is invoked once per
-- day just after midnight, to produce usage data with daily granularity, then
-- a reasonably accurate monthly bandwidth summary for a given user could be
-- obtained by queriing this table with:
--
-- SELECT
-- STRFTIME('%Y-%m',CURRENT_TIMESTAMP) AS month,
-- SUM(acctinputoctets)*1.0/1000/1000/1000 AS gb_in,
-- SUM(acctoutputoctets)*1.0/1000/1000/1000 AS gb_out
-- FROM
-- data_usage_by_period
-- WHERE
-- username='bob' AND
-- period_end IS NOT NULL
-- GROUP BY
-- month;
--
-- 2019-07|5.782279231|50.545664824
-- 2019-08|4.230543344|48.523096424
-- 2019-09|4.847360599|48.631835488
-- 2019-10|6.456763254|51.686231937
-- 2019-11|6.362537735|52.385710572
-- 2019-12|4.301524442|50.762240277
-- 2020-01|5.436280545|49.067775286
--
CREATE TABLE data_usage_by_period (
username text,
period_start datetime,
period_end datetime,
acctinputoctets bigint,
acctoutputoctets bigint,
PRIMARY KEY (username, period_start)
);
CREATE INDEX idx_data_usage_by_period_period_start ON data_usage_by_period(period_start);

0 comments on commit 0252e1e

Please sign in to comment.