Currently supported by MySQL, PostgreSQL and SQLite.
END$$
DELIMITER ;
+
+
+-- ------------------------------------------------------
+-- - "Lightweight" Accounting-On/Off strategy resources -
+-- ------------------------------------------------------
+--
+-- The following resources are for use only when the "lightweight"
+-- Accounting-On/Off strategy is enabled in queries.conf.
+--
+-- Instead of bulk closing the radacct sessions belonging to a reloaded NAS,
+-- this strategy leaves them open and records the NAS reload time in the
+-- nasreload table.
+--
+-- Where applicable, the onus is on the administator to:
+--
+-- * Consider the nas reload times when deriving a list of
+-- active/inactive sessions, and when determining the duration of sessions
+-- interrupted by a NAS reload. (Refer to the view below.)
+--
+-- * Close the affected sessions out of band. (Refer to the SP below.)
+--
+--
+-- The radacct_with_reloads view presents the radacct table with two additional
+-- columns: acctstoptime_with_reloads and acctsessiontime_with_reloads
+--
+-- Where the session isn't closed (acctstoptime IS NULL), yet it started before
+-- the last reload of the NAS (radacct.acctstarttime < nasreload.reloadtime),
+-- the derived columns are set based on the reload time of the NAS (effectively
+-- the point in time that the session was interrupted.)
+--
+CREATE VIEW radacct_with_reloads AS
+SELECT
+ a.*,
+ COALESCE(a.acctstoptime,
+ IF(a.acctstarttime < n.reloadtime, n.reloadtime, NULL)
+ ) AS acctstoptime_with_reloads,
+ COALESCE(a.acctsessiontime,
+ IF(a.acctstoptime IS NULL AND a.acctstarttime < n.reloadtime,
+ UNIX_TIMESTAMP(n.reloadtime) - UNIX_TIMESTAMP(a.acctstarttime), NULL)
+ ) AS acctsessiontime_with_reloads
+FROM radacct a
+LEFT OUTER JOIN nasreload n USING (nasipaddress);
+
+
+--
+-- It may be desirable to periodically "close" radacct sessions belonging to a
+-- reloaded NAS, replicating the "bulk close" Accounting-On/Off behaviour,
+-- just not in real time.
+--
+-- The fr_radacct_close_after_reload SP will set radacct.acctstoptime to
+-- nasreload.reloadtime, calculate the corresponding radacct.acctsessiontime,
+-- and set acctterminatecause to "NAS reboot" for interrupted sessions. It
+-- does so in batches, which avoids long-lived locks on the affected rows.
+--
+-- It can be invoked as follows:
+--
+-- CALL fr_radacct_close_after_reload();
+--
+-- Note: This SP walks radacct in strides of v_batch_size. It will typically
+-- skip closed and ongoing sessions at a rate significantly faster than
+-- 100,000 rows per second and process batched updates faster than 20,000
+-- orphaned sessions per second. If this isn't fast enough then you should
+-- really consider using a custom schema that includes partitioning by
+-- nasipaddress or acct{start,stop}time.
+--
+DELIMITER $$
+
+DROP PROCEDURE IF EXISTS fr_radacct_close_after_reload;
+CREATE PROCEDURE fr_radacct_close_after_reload ()
+SQL SECURITY INVOKER
+BEGIN
+
+ DECLARE v_a BIGINT(21);
+ DECLARE v_z BIGINT(21);
+ DECLARE v_updated BIGINT(21) DEFAULT 0;
+ DECLARE v_last_report DATETIME DEFAULT 0;
+ DECLARE v_last BOOLEAN DEFAULT FALSE;
+ DECLARE v_batch_size INT(12);
+
+ --
+ -- This works for many circumstances
+ --
+ SET v_batch_size = 2500;
+
+ SELECT MIN(radacctid) INTO v_a FROM radacct WHERE acctstoptime IS NULL;
+
+ update_loop: LOOP
+
+ SET v_z = NULL;
+ SELECT radacctid INTO v_z FROM radacct WHERE radacctid > v_a ORDER BY radacctid LIMIT v_batch_size,1;
+
+ IF v_z IS NULL THEN
+ SELECT MAX(radacctid) INTO v_z FROM radacct;
+ SET v_last = TRUE;
+ END IF;
+
+ UPDATE radacct a INNER JOIN nasreload n USING (nasipaddress)
+ SET
+ acctstoptime = n.reloadtime,
+ acctsessiontime = UNIX_TIMESTAMP(n.reloadtime) - UNIX_TIMESTAMP(acctstarttime),
+ acctterminatecause = 'NAS reboot'
+ WHERE
+ radacctid BETWEEN v_a AND v_z
+ AND acctstoptime IS NULL
+ AND acctstarttime < n.reloadtime;
+
+ SET v_updated = v_updated + ROW_COUNT();
+
+ SET v_a = v_z + 1;
+
+ --
+ -- Periodically report how far we've got
+ --
+ IF v_last_report != NOW() OR v_last THEN
+ SELECT v_z AS latest_radacctid, v_updated AS sessions_closed;
+ SET v_last_report = NOW();
+ END IF;
+
+ IF v_last THEN
+ LEAVE update_loop;
+ END IF;
+
+ END LOOP;
+
+END$$
+
+DELIMITER ;
type {
accounting-on {
+
+ #
+ # "Bulk update" Accounting-On/Off strategy.
+ #
+ # Immediately terminate all sessions associated with a
+ # given NAS.
#
- # Bulk terminate all sessions associated with a given NAS
+ # Note: If a large number of sessions require closing
+ # then the bulk update may be take a long time to run
+ # and lock an excessive number of rows. See the
+ # strategy below for an alternative approach that does
+ # not touch the radacct session data.
#
query = "\
UPDATE ${....acct_table1} \
AND acctstarttime <= ${....event_timestamp}"
#
+ # "Lightweight" Accounting-On/Off strategy.
+ #
+ # Record the reload time of the NAS and let the
+ # administrator actually close the sessions in radacct
+ # out-of-band, if desired.
+ #
+ # Implementation advice, together with a stored
+ # procedure for closing sessions and a view showing
+ # the effective stop time of each session is provided
+ # in process-radacct.sql.
+ #
+ # To enable this strategy, just change the previous
+ # query to "-query", and this one to "query". The
+ # previous one will be ignored, and this one will be
+ # enabled.
+ #
+ -query = "\
+ INSERT INTO nasreload \
+ SET \
+ nasipaddress = '%{NAS-IP-Address}', \
+ reloadtime = ${....event_timestamp} \
+ ON DUPLICATE KEY UPDATE reloadtime = ${....event_timestamp}"
+
# If there are no open user sessions, then the previous query
# will return "no rows updated". The server will then fall through
# to the next query, which is just "yes, that's fine".
#
query = "SELECT true"
+
}
accounting-off {
description varchar(200) DEFAULT 'RADIUS Client',
PRIMARY KEY (id),
KEY nasname (nasname)
-);
+) ENGINE = INNODB;
+
+#
+# Table structure for table 'nasreload'
+#
+CREATE TABLE IF NOT EXISTS nasreload (
+ nasipaddress varchar(15) NOT NULL,
+ reloadtime datetime NOT NULL,
+ PRIMARY KEY (nasipaddress)
+) ENGINE = INNODB;
-- -*- text -*-
--
--- admin.sql -- MySQL commands for creating the RADIUS user.
+-- setup.sql -- MySQL commands for creating the RADIUS user.
--
-- WARNING: You should change 'localhost' and 'radpass'
-- to something else. Also update raddb/mods-available/sql
--
CREATE USER 'radius'@'localhost' IDENTIFIED BY 'radpass';
--- The server can read any table in SQL
-GRANT SELECT ON radius.* TO 'radius'@'localhost';
+--
+-- The server can read the authorisation data
+--
+GRANT SELECT ON radius.radcheck TO 'radius'@'localhost';
+GRANT SELECT ON radius.radreply TO 'radius'@'localhost';
+GRANT SELECT ON radius.radusergroup TO 'radius'@'localhost';
+GRANT SELECT ON radius.radgroupcheck TO 'radius'@'localhost';
+GRANT SELECT ON radius.radgroupreply TO 'radius'@'localhost';
+
+--
+-- The server can write accounting and post-auth data
+--
+GRANT SELECT, INSERT, UPDATE ON radius.radacct TO 'radius'@'localhost';
+GRANT SELECT, INSERT, UPDATE ON radius.radpostauth TO 'radius'@'localhost';
--- The server can write to the accounting and post-auth logging table.
--
--- i.e.
-GRANT ALL on radius.radacct TO 'radius'@'localhost';
-GRANT ALL on radius.radpostauth TO 'radius'@'localhost';
+-- The server can read the NAS data
+--
+GRANT SELECT ON radius.nas TO 'radius'@'localhost';
+
+--
+-- In the case of the "lightweight accounting-on/off" strategy, the server also
+-- records NAS reload times
+--
+GRANT SELECT, INSERT, UPDATE ON radius.nasreload TO 'radius'@'localhost';
END
$$;
+
+
+-- ------------------------------------------------------
+-- - "Lightweight" Accounting-On/Off strategy resources -
+-- ------------------------------------------------------
+--
+-- The following resources are for use only when the "lightweight"
+-- Accounting-On/Off strategy is enabled in queries.conf.
+--
+-- Instead of bulk closing the radacct sessions belonging to a reloaded NAS,
+-- this strategy leaves them open and records the NAS reload time in the
+-- nasreload table.
+--
+-- Where applicable, the onus is on the administator to:
+--
+-- * Consider the nas reload times when deriving a list of
+-- active/inactive sessions, and when determining the duration of sessions
+-- interrupted by a NAS reload. (Refer to the view below.)
+--
+-- * Close the affected sessions out of band. (Refer to the SP below.)
+--
+--
+-- The radacct_with_reloads view presents the radacct table with two additional
+-- columns: acctstoptime_with_reloads and acctsessiontime_with_reloads
+--
+-- Where the session isn't closed (acctstoptime IS NULL), yet it started before
+-- the last reload of the NAS (radacct.acctstarttime < nasreload.reloadtime),
+-- the derived columns are set based on the reload time of the NAS (effectively
+-- the point in time that the session was interrupted.)
+--
+CREATE VIEW radacct_with_reloads AS
+SELECT
+ a.*,
+ COALESCE(a.AcctStopTime,
+ CASE WHEN a.AcctStartTime < n.ReloadTime THEN n.ReloadTime END
+ ) AS AcctStopTime_With_Reloads,
+ COALESCE(a.AcctSessionTime,
+ CASE WHEN a.AcctStopTime IS NULL AND a.AcctStartTime < n.ReloadTime THEN
+ EXTRACT(EPOCH FROM (n.ReloadTime - a.AcctStartTime))
+ END
+ ) AS AcctSessionTime_With_Reloads
+FROM radacct a
+LEFT OUTER JOIN nasreload n USING (nasipaddress);
+
+
+--
+-- It may be desirable to periodically "close" radacct sessions belonging to a
+-- reloaded NAS, replicating the "bulk close" Accounting-On/Off behaviour,
+-- just not in real time.
+--
+-- The fr_radacct_close_after_reload SP will set radacct.acctstoptime to
+-- nasreload.reloadtime, calculate the corresponding radacct.acctsessiontime,
+-- and set acctterminatecause to "NAS reboot" for interrupted sessions. It
+-- does so in batches, which avoids long-lived locks on the affected rows.
+--
+-- It can be invoked as follows:
+--
+-- CALL fr_radacct_close_after_reload();
+--
+-- Note: This SP requires PostgreSQL >= 11 which was the first version to
+-- introduce PROCEDUREs which permit transaction control. This allows COMMIT
+-- to be called to incrementally apply successive batch updates prior to the
+-- end of the procedure. Prior to version 11 there exists only FUNCTIONs that
+-- execute atomically. You can convert this procedure to a function, but by
+-- doing so you are really no better off than performing a single,
+-- long-running bulk update.
+--
+-- Note: This SP walks radacct in strides of v_batch_size. It will typically
+-- skip closed and ongoing sessions at a rate significantly faster than
+-- 500,000 rows per second and process batched updates faster than 25,000
+-- orphaned sessions per second. If this isn't fast enough then you should
+-- really consider using a custom schema that includes partitioning by
+-- nasipaddress or acct{start,stop}time.
+--
+CREATE OR REPLACE PROCEDURE fr_radacct_close_after_reload ()
+LANGUAGE plpgsql
+AS $$
+
+DECLARE v_a bigint;
+DECLARE v_z bigint;
+DECLARE v_updated bigint DEFAULT 0;
+DECLARE v_last_report bigint DEFAULT 0;
+DECLARE v_now bigint;
+DECLARE v_last boolean DEFAULT false;
+DECLARE v_rowcount integer;
+
+--
+-- This works for many circumstances
+--
+DECLARE v_batch_size CONSTANT integer := 2500;
+
+BEGIN
+
+ SELECT MIN(RadAcctId) INTO v_a FROM radacct WHERE AcctStopTime IS NULL;
+
+ LOOP
+
+ v_z := NULL;
+ SELECT RadAcctId INTO v_z FROM radacct WHERE RadAcctId > v_a ORDER BY RadAcctId OFFSET v_batch_size LIMIT 1;
+
+ IF v_z IS NULL THEN
+ SELECT MAX(RadAcctId) INTO v_z FROM radacct;
+ v_last := true;
+ END IF;
+
+ UPDATE radacct a
+ SET
+ AcctStopTime = n.reloadtime,
+ AcctSessionTime = EXTRACT(EPOCH FROM (n.ReloadTime - a.AcctStartTime)),
+ AcctTerminateCause = 'NAS reboot'
+ FROM nasreload n
+ WHERE
+ a.NASIPAddress = n.NASIPAddress
+ AND RadAcctId BETWEEN v_a AND v_z
+ AND AcctStopTime IS NULL
+ AND AcctStartTime < n.ReloadTime;
+
+ GET DIAGNOSTICS v_rowcount := ROW_COUNT;
+ v_updated := v_updated + v_rowcount;
+
+ COMMIT; -- Make the update visible
+
+ v_a := v_z + 1;
+
+ --
+ -- Periodically report how far we've got
+ --
+ SELECT EXTRACT(EPOCH FROM CURRENT_TIMESTAMP) INTO v_now;
+ IF v_last_report != v_now OR v_last THEN
+ RAISE NOTICE 'RadAcctID: %; Sessions closed: %', v_z, v_updated;
+ v_last_report := v_now;
+ END IF;
+
+ EXIT WHEN v_last;
+
+ END LOOP;
+
+END
+$$;
type {
accounting-on {
+
+ #
+ # "Bulk update" Accounting-On/Off strategy.
+ #
+ # Immediately terminate all sessions associated with a
+ # given NAS.
+ #
+ # Note: If a large number of sessions require closing
+ # then the bulk update may be take a long time to run
+ # and lock an excessive number of rows. See the
+ # strategy below for an alternative approach that does
+ # not touch the radacct session data.
+ #
query = "\
UPDATE ${....acct_table1} \
SET \
AND AcctStartTime <= ${....event_timestamp}"
#
+ # "Lightweight" Accounting-On/Off strategy.
+ #
+ # Record the reload time of the NAS and let the
+ # administrator actually close the sessions in radacct
+ # out-of-band, if desired.
+ #
+ # Implementation advice, together with a stored
+ # procedure for closing sessions and a view showing
+ # the effective stop time of each session is provided
+ # in process-radacct.sql.
+ #
+ # To enable this strategy, just change the previous
+ # query to "-query", and this one to "query". The
+ # previous one will be ignored, and this one will be
+ # enabled.
+ #
+ -query = "\
+ INSERT INTO nasreload (NASIPAddress, ReloadTime) \
+ VALUES ('%{NAS-IP-Address}', ${....event_timestamp}) \
+ ON CONFLICT ON (NASIPAddress) \
+ DO UPDATE SET \
+ ReloadTime = ${....event_timestamp}"
+
# If there are no open user sessions, then the previous query
# will return "no rows updated". The server will then fall through
# to the next query, which is just "yes, that's fine".
#
query = "SELECT true"
+
}
accounting-off {
--
-- Postgresql schema for FreeRADIUS
--
--- All field lengths need checking as some are still suboptimal. -pnixon 2003-07-13
---
---
--
-- Table structure for table 'radacct'
--
--- Note: Column type bigserial does not exist prior to Postgres 7.2
--- If you run an older version you need to change this to serial
---
-CREATE TABLE radacct (
+CREATE TABLE IF NOT EXISTS radacct (
RadAcctId bigserial PRIMARY KEY,
AcctSessionId text NOT NULL,
AcctUniqueId text NOT NULL UNIQUE,
description text
);
create index nas_nasname on nas (nasname);
+
+/*
+ * Table structure for table 'nasreload'
+ */
+CREATE TABLE IF NOT EXISTS nasreload (
+ NASIPAddress inet PRIMARY KEY,
+ ReloadTime timestamp with time zone NOT NULL
+);
--
--- admin.sql -- PostgreSQL commands for creating the RADIUS user.
+-- setup.sql -- PostgreSQL commands for creating the RADIUS user.
--
-- WARNING: You should change 'localhost' and 'radpass'
-- to something else. Also update raddb/mods-available/sql
CREATE USER radius WITH PASSWORD 'radpass';
--
--- The server can read any table in SQL
+-- The server can read the authorisation data
--
GRANT SELECT ON radcheck TO radius;
GRANT SELECT ON radreply TO radius;
+GRANT SELECT ON radusergroup TO radius;
GRANT SELECT ON radgroupcheck TO radius;
GRANT SELECT ON radgroupreply TO radius;
-GRANT SELECT ON radusergroup TO radius;
-GRANT SELECT ON nas TO radius;
--
--- The server can write to the accounting and post-auth logging table.
+-- The server can write accounting and post-auth data
--
GRANT SELECT, INSERT, UPDATE on radacct TO radius;
GRANT SELECT, INSERT, UPDATE on radpostauth TO radius;
--
--- Grant permissions on sequences
+-- The server can read the NAS data
+--
+GRANT SELECT ON nas TO radius;
+
+--
+-- In the case of the "lightweight accounting-on/off" strategy, the server also
+-- records NAS reload times
+--
+GRANT SELECT, INSERT, UPDATE ON nasreload TO radius;
+
+--
+-- Grant permissions on sequences
--
-GRANT USAGE, SELECT ON SEQUENCE nas_id_seq TO radius;
-GRANT USAGE, SELECT ON SEQUENCE radacct_radacctid_seq TO radius;
GRANT USAGE, SELECT ON SEQUENCE radcheck_id_seq TO radius;
+GRANT USAGE, SELECT ON SEQUENCE radreply_id_seq TO radius;
+GRANT USAGE, SELECT ON SEQUENCE radusergroup_id_seq TO radius;
GRANT USAGE, SELECT ON SEQUENCE radgroupcheck_id_seq TO radius;
GRANT USAGE, SELECT ON SEQUENCE radgroupreply_id_seq TO radius;
+GRANT USAGE, SELECT ON SEQUENCE radacct_radacctid_seq TO radius;
GRANT USAGE, SELECT ON SEQUENCE radpostauth_id_seq TO radius;
-GRANT USAGE, SELECT ON SEQUENCE radreply_id_seq TO radius;
-GRANT USAGE, SELECT ON SEQUENCE radusergroup_id_seq TO radius;
+GRANT USAGE, SELECT ON SEQUENCE nas_id_seq TO radius;
--- /dev/null
+#!/usr/bin/perl -Tw
+
+#
+# main/sqlite/process-radacct-close-after_reload.pl -- Script for
+# processing radacct entries to close sessions interrupted by a NAS reload
+#
+# Requires the DBD::SQLite module: perl-DBD-SQLite (RedHat); libdbd-sqlite3-perl (Debian)
+#
+# $Id$
+#
+# It may be desirable to periodically "close" radacct sessions belonging to a
+# reloaded NAS, replicating the "bulk close" Accounting-On/Off behaviour,
+# just not in real time.
+#
+# This script will set radacct.acctstoptime to nasreload.reloadtime, calculate
+# the corresponding radacct.acctsessiontime, and set acctterminatecause to
+# "NAS reboot" for interrupted sessions. It does so in batches, which avoids a
+# single long-lived lock on the table.
+#
+# It can be invoked as follows:
+#
+# ./process-radacct-close-after-reload.pl <sqlite_db_file>
+#
+# Note: This script walks radacct in strides of v_batch_size. It will
+# typically skip closed and ongoing sessions at a rate significantly faster
+# than 10,000 rows per second and process batched updates faster than 5000
+# orphaned sessions per second. If this isn't fast enough then you should
+# really consider using a server-based database for accounting purposes.
+#
+
+use strict;
+use DBI;
+
+#
+# Fine for most purposes
+#
+my $batch_size = 2500;
+
+if ($#ARGV != 0) {
+ print "Usage: process-radacct-close-after_reload.pl SQLITE_DB_FILE\n\n";
+ exit 1;
+}
+die "The SQLite database must exist: $ARGV[0]" unless -r $ARGV[0];
+
+
+my $dbh = DBI->connect("DBI:SQLite:dbname=$ARGV[0]", '', '', { RaiseError => 1 }) or die $DBI::errstr;
+
+#
+# There is no UPDATE ... JOIN/FROM in SQLite, so we have to resort to this
+# construction # which does not provide an accurate rows updated count...
+#
+my $sth_upd = $dbh->prepare(<<'EOF');
+ UPDATE radacct
+ SET
+ acctstoptime = (
+ SELECT COALESCE(acctstoptime, CASE WHEN radacct.acctstarttime < reloadtime THEN reloadtime END)
+ FROM nasreload WHERE nasipaddress = radacct.nasipaddress
+ ),
+ acctsessiontime = (
+ SELECT COALESCE(acctsessiontime,
+ CASE WHEN radacct.acctstoptime IS NULL AND radacct.acctstarttime < reloadtime THEN
+ CAST((julianday(reloadtime) - julianday(radacct.acctstarttime)) * 86400 AS integer)
+ END)
+ FROM nasreload WHERE nasipaddress = radacct.nasipaddress
+ ),
+ acctterminatecause = (
+ SELECT
+ CASE WHEN radacct.acctstoptime IS NULL AND radacct.acctstarttime < reloadtime THEN
+ 'NAS reboot'
+ ELSE
+ acctterminatecause
+ END
+ FROM nasreload WHERE nasipaddress = radacct.nasipaddress
+ )
+ WHERE
+ radacctid BETWEEN ? AND ?
+ AND acctstoptime IS NULL
+EOF
+
+my $sth = $dbh->prepare('SELECT MIN(radacctid), MAX(radacctid) FROM radacct WHERE acctstoptime IS NULL');
+$sth->execute() or die $DBI::errstr;
+(my $a, my $m) = $sth->fetchrow_array();
+$sth->finish;
+
+my $sth_nxt = $dbh->prepare('SELECT radacctid FROM radacct WHERE radacctid > ? ORDER BY radacctid LIMIT ?,1');
+
+
+my $last = 0;
+my $last_report = 0;
+
+unless ($last) {
+
+ $sth_nxt->execute($a, $batch_size) or die $DBI::errstr;
+ (my $z) = $sth_nxt->fetchrow_array();
+
+ unless ($z) {
+ $z = $m;
+ $last = 1;
+ }
+
+ my $rc = $sth_upd->execute($a, $z) or die $DBI::errstr;
+
+ $a = $z + 1;
+
+ #
+ # Periodically report how far we've got
+ #
+ my $now = time();
+ if ($last_report != $now || $last) {
+ print "RadAcctID: $z\n";
+ $last_report = $now;
+ }
+
+}
+
+$sth_upd->finish;
+$sth_nxt->finish;
+
+$dbh->disconnect;
#!/bin/sh
#
-# main/sqlite/process-radacct-refresh.sh -- Schema extensions and script for processing radacct entries
+# main/sqlite/process-radacct-new-data-usage-period.sh -- Script for
+# processing radacct entries to extract daily usage
#
# $Id$
#
if [ "$#" -ne 1 ]; then
- echo "Usage: process-radacct-refresh.sh SQLITE_DB_FILE" 2>&1
+ echo "Usage: process-radacct-new-data-usage-period.sh SQLITE_DB_FILE" 2>&1
exit 1
fi
# -*- text -*-
#
-# main/sqlite/process-radacct.sql -- Schema extensions and script for processing radacct entries
+# main/sqlite/process-radacct.sql -- Schema extensions for processing radacct entries
#
# $Id$
-- for arbitrary periods.
--
-- The data_usage_by_period table is populated by periodically calling the
--- process-radacct-refresh.sh script.
+-- process-radacct-new-data-usage-period.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
);
CREATE INDEX idx_data_usage_by_period_period_start ON data_usage_by_period(period_start);
CREATE INDEX idx_data_usage_by_period_period_end ON data_usage_by_period(period_end);
+
+
+-- ------------------------------------------------------
+-- - "Lightweight" Accounting-On/Off strategy resources -
+-- ------------------------------------------------------
+--
+-- The following resources are for use only when the "lightweight"
+-- Accounting-On/Off strategy is enabled in queries.conf.
+--
+-- Instead of bulk closing the radacct sessions belonging to a reloaded NAS,
+-- this strategy leaves them open and records the NAS reload time in the
+-- nasreload table.
+--
+-- Where applicable, the onus is on the administator to:
+--
+-- * Consider the nas reload times when deriving a list of
+-- active/inactive sessions, and when determining the duration of sessions
+-- interrupted by a NAS reload. (Refer to the view below.)
+--
+-- * Close the affected sessions out of band. (Refer to the
+-- process-radacct-close-after_reload.pl script.)
+--
+-- The radacct_with_reloads view presents the radacct table with two additional
+-- columns: acctstoptime_with_reloads and acctsessiontime_with_reloads
+--
+-- Where the session isn't closed (acctstoptime IS NULL), yet it started before
+-- the last reload of the NAS (radacct.acctstarttime < nasreload.reloadtime),
+-- the derived columns are set based on the reload time of the NAS (effectively
+-- the point in time that the session was interrupted.)
+--
+CREATE VIEW radacct_with_reloads AS
+SELECT
+ a.*,
+ COALESCE(a.AcctStopTime,
+ CASE WHEN a.AcctStartTime < n.ReloadTime THEN n.ReloadTime END
+ ) AS AcctStopTime_With_Reloads,
+ COALESCE(a.AcctSessionTime,
+ CASE WHEN a.AcctStopTime IS NULL AND a.AcctStartTime < n.ReloadTime THEN
+ CAST((julianday(n.ReloadTime) - julianday(a.AcctStartTime)) * 86400 AS integer)
+ END
+ ) AS AcctSessionTime_With_Reloads
+FROM radacct a
+LEFT OUTER JOIN nasreload n USING (nasipaddress);
type {
accounting-on {
+
+ #
+ # "Bulk update" Accounting-On/Off strategy.
+ #
+ # Immediately terminate all sessions associated with a
+ # given NAS.
#
- # Bulk terminate all sessions associated with a given NAS
+ # Note: If a large number of sessions require closing
+ # then the bulk update may be take a long time to run
+ # and lock an excessive number of rows. See the
+ # strategy below for an alternative approach that does
+ # not touch the radacct session data.
#
query = "\
UPDATE ${....acct_table1} \
AND nasipaddress = '%{NAS-IP-Address}' \
AND acctstarttime <= ${....event_timestamp}"
+ # "Lightweight" Accounting-On/Off strategy.
+ #
+ # Record the reload time of the NAS and let the
+ # administrator actually close the sessions in radacct
+ # out-of-band, if desired.
+ #
+ # Implementation advice, together with a stored
+ # procedure for closing sessions and a view showing
+ # the effective stop time of each session is provided
+ # in process-radacct.sql.
+ #
+ # To enable this strategy, just change the previous
+ # query to "-query", and this one to "query". The
+ # previous one will be ignored, and this one will be
+ # enabled.
+ #
+ -query = "\
+ INSERT OR REPLACE INTO nasreload (nasipaddress, reloadtime) \
+ VALUES ('%{NAS-IP-Address}', ${....event_timestamp})"
+
#
# If there are no open user sessions, then the previous query
# will return "no rows updated". The server will then fall through
# to the next query, which is just "yes, that's fine".
#
query = "SELECT true"
+
}
accounting-off {
description varchar(200) DEFAULT 'RADIUS Client'
);
CREATE INDEX nasname ON nas(nasname);
+
+--
+-- Table structure for table 'nasreload'
+--
+CREATE TABLE IF NOT EXISTS nasreload (
+ nasipaddress varchar(15) PRIMARY KEY,
+ reloadtime datetime NOT NULL
+);