From: Arran Cudbard-Bell Date: Wed, 6 Mar 2013 22:21:45 +0000 (-0500) Subject: Basic Sqlite Schema X-Git-Tag: release_3_0_0_beta1~811 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=f8acf5104ea5790701a7ba1bbd09ae99f267175d;p=thirdparty%2Ffreeradius-server.git Basic Sqlite Schema --- diff --git a/raddb/sql/main/sqlite/queries.conf b/raddb/sql/main/sqlite/queries.conf new file mode 100644 index 00000000000..e79b6e3c1fb --- /dev/null +++ b/raddb/sql/main/sqlite/queries.conf @@ -0,0 +1,404 @@ +# -*- text -*- +## +## dialup.conf -- MySQL configuration for default schema (schema.sql) +## +## $Id$ + + # Safe characters list for sql queries. Everything else is replaced + # with their mime-encoded equivalents. + # The default list should be ok + #safe-characters = "@abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789.-_: /" + + ####################################################################### + # Connection config + ####################################################################### + # The character set is not configurable. The default character set of + # the mysql client library is used. To control the character set, + # create/edit my.cnf (typically in /etc/mysql/my.cnf or /etc/my.cnf) + # and enter + # [client] + # default-character-set = utf8 + # + + ####################################################################### + # Query config: Username + ####################################################################### + # This is the username that will get substituted, escaped, and added + # as attribute 'SQL-User-Name'. '%{SQL-User-Name}' should be used below + # everywhere a username substitution is needed so you you can be sure + # the username passed from the client is escaped properly. + # + # Uncomment the next line, if you want the sql_user_name to mean: + # + # Use Stripped-User-Name, if it's there. + # Else use User-Name, if it's there, + # Else use hard-coded string "DEFAULT" as the user name. + #sql_user_name = "%{%{Stripped-User-Name}:-%{%{User-Name}:-DEFAULT}}" + # + sql_user_name = "%{User-Name}" + + ####################################################################### + # Default profile + ####################################################################### + # This is the default profile. It is found in SQL by group membership. + # That means that this profile must be a member of at least one group + # which will contain the corresponding check and reply items. + # This profile will be queried in the authorize section for every user. + # The point is to assign all users a default profile without having to + # manually add each one to a group that will contain the profile. + # The SQL module will also honor the User-Profile attribute. This + # attribute can be set anywhere in the authorize section (ie the users + # file). It is found exactly as the default profile is found. + # If it is set then it will *overwrite* the default profile setting. + # The idea is to select profiles based on checks on the incoming packets, + # not on user group membership. For example: + # -- users file -- + # DEFAULT Service-Type == Outbound-User, User-Profile := "outbound" + # DEFAULT Service-Type == Framed-User, User-Profile := "framed" + # + # By default the default_user_profile is not set + # + #default_user_profile = "DEFAULT" + + ####################################################################### + # NAS Query + ####################################################################### + # This query retrieves the radius clients + # + # 0. Row ID (currently unused) + # 1. Name (or IP address) + # 2. Shortname + # 3. Type + # 4. Secret + # 5. Server + ####################################################################### + + nas_query = "SELECT id, nasname, shortname, type, secret, server FROM ${nas_table}" + + ####################################################################### + # Authorization Queries + ####################################################################### + # These queries compare the check items for the user + # in ${authcheck_table} and setup the reply items in + # ${authreply_table}. You can use any query/tables + # you want, but the return data for each row MUST + # be in the following order: + # + # 0. Row ID (currently unused) + # 1. UserName/GroupName + # 2. Item Attr Name + # 3. Item Attr Value + # 4. Item Attr Operation + ####################################################################### + # Use these for case sensitive usernames. +# authorize_check_query = "\ +# SELECT id, username, attribute, value, op \ +# FROM ${authcheck_table} \ +# WHERE username = BINARY '%{SQL-User-Name}' \ +# ORDER BY id" + +# authorize_reply_query = "\ +# SELECT id, username, attribute, value, op \ +# FROM ${authreply_table} \ +# WHERE username = BINARY '%{SQL-User-Name}' \ +# ORDER BY id" + + # The default queries are case insensitive. (for compatibility with + # older versions of FreeRADIUS) + authorize_check_query = "\ + SELECT id, username, attribute, value, op \ + FROM ${authcheck_table} \ + WHERE username = '%{SQL-User-Name}' \ + ORDER BY id" + + authorize_reply_query = "\ + SELECT id, username, attribute, value, op \ + FROM ${authreply_table} \ + WHERE username = '%{SQL-User-Name}' \ + ORDER BY id" + + # Use these for case sensitive usernames. +# group_membership_query = "\ +# SELECT groupname \ +# FROM ${usergroup_table} \ +# WHERE username = BINARY '%{SQL-User-Name}' \ +# ORDER BY priority" + + group_membership_query = "\ + SELECT groupname \ + FROM ${usergroup_table} \ + WHERE username = '%{SQL-User-Name}' \ + ORDER BY priority" + + authorize_group_check_query = "\ + SELECT id, groupname, attribute, \ + Value, op \ + FROM ${groupcheck_table} \ + WHERE groupname = '%{Sql-Group}' \ + ORDER BY id" + + authorize_group_reply_query = "\ + SELECT id, groupname, attribute, \ + value, op \ + FROM ${groupreply_table} \ + WHERE groupname = '%{Sql-Group}' \ + ORDER BY id" + + ####################################################################### + # Simultaneous Use Checking Queries + ####################################################################### + # simul_count_query - query for the number of current connections + # - If this is not defined, no simultaneouls use checking + # - will be performed by this module instance + # simul_verify_query - query to return details of current connections + # for verification + # - Leave blank or commented out to disable verification step + # - Note that the returned field order should not be changed. + ####################################################################### + + # Uncomment simul_count_query to enable simultaneous use checking +# simul_count_query = "\ +# SELECT COUNT(*) \ +# FROM ${acct_table1} \ +# WHERE username = '%{SQL-User-Name}' \ +# AND acctstoptime IS NULL" + + simul_verify_query = "\ + SELECT radacctid, acctsessionid, username, \ + nasipaddress, nasportid, framedipaddress, \ + callingstationid, framedprotocol \ + FROM ${acct_table1} \ + WHERE username = '%{SQL-User-Name}' \ + AND acctstoptime IS NULL" + + ####################################################################### + # Accounting and Post-Auth Queries + ####################################################################### + # These queries insert/update accounting and authentication records. + # The query to use is determined by the value of 'reference'. + # This value is used as a configuration path and should resolve to one + # or more 'query's. If reference points to multiple queries, and a query + # fails, the next query is executed. + # + # Behaviour is identical to the old 1.x/2.x module, except we can now + # fail between N queries, and query selection can be based on any + # combination of attributes, or custom 'Acct-Status-Type' values. + ####################################################################### + accounting { + reference = "%{tolower:type.%{Acct-Status-Type}.query}" + + # All SQL statements are logged to this file. + # This file is preferred to the "logfile" set in + # the mods-enabled/sql file. The filename is dynamically + # expanded at run time, so you can use %H, etc., just + # as with the detail file. +# logfile = ${logdir}/accounting.sql + + column_list = "\ + acctsessionid, acctuniqueid, username, \ + realm, nasipaddress, nasportid, \ + nasporttype, acctstarttime, acctupdatetime, \ + acctstoptime, acctsessiontime, acctauthentic, \ + connectinfo_start, connectinfo_stop, acctinputoctets, \ + acctoutputoctets, calledstationid, callingstationid, \ + acctterminatecause, servicetype, framedprotocol, \ + framedipaddress" + + type { + accounting-on { + # + # Bulk terminate all sessions associated with a given NAS + # + query = "\ + UPDATE ${....acct_table1} \ + SET \ + acctstoptime = FROM_UNIXTIME(\ + %{integer:Event-Timestamp}), \ + acctsessiontime = '%{integer:Event-Timestamp}' \ + - UNIX_TIMESTAMP(acctstarttime), \ + acctterminatecause = '%{Acct-Terminate-Cause}' \ + WHERE acctstoptime IS NULL \ + AND nasipaddress = '%{NAS-IP-Address}' \ + AND acctstarttime <= FROM_UNIXTIME(\ + %{integer:Event-Timestamp})" + } + + accounting-off { + query = "${..accounting-on.query}" + } + + start { + # + # Insert a new record into the sessions table + # + query = "\ + INSERT INTO ${....acct_table1} \ + (${...column_list}) \ + VALUES \ + ('%{Acct-Session-Id}', \ + '%{Acct-Unique-Session-Id}', \ + '%{SQL-User-Name}', \ + '%{Realm}', \ + '%{NAS-IP-Address}', \ + '%{NAS-Port}', \ + '%{NAS-Port-Type}', \ + FROM_UNIXTIME(%{integer:Event-Timestamp}), \ + FROM_UNIXTIME(%{integer:Event-Timestamp}), \ + NULL, \ + '0', \ + '%{Acct-Authentic}', \ + '%{Connect-Info}', \ + '', \ + '0', \ + '0', \ + '%{Called-Station-Id}', \ + '%{Calling-Station-Id}', \ + '', \ + '%{Service-Type}', \ + '%{Framed-Protocol}', \ + '%{Framed-IP-Address}')" + + # + # Key constraints prevented us from inserting a new session, + # use the alternate query to update an existing session. + # + query = "\ + UPDATE ${....acct_table1} SET \ + acctstarttime = FROM_UNIXTIME(\ + %{integer:Event-Timestamp}), \ + acctupdatetime = FROM_UNIXTIME(\ + %{integer:Event-Timestamp}), \ + connectinfo_start = '%{Connect-Info}' \ + WHERE acctsessionid = '%{Acct-Session-Id}' \ + AND username = '%{SQL-User-Name}' \ + AND nasipaddress = '%{NAS-IP-Address}'" + } + + interim-update { + # + # Update an existing session and calculate the interval + # between the last data we received for the session and this + # update. This can be used to find stale sessions. + # + query = "\ + UPDATE ${....acct_table1} \ + SET \ + acctupdatetime = (\ + @acctupdatetime_old:=acctupdatetime), \ + acctupdatetime = FROM_UNIXTIME(\ + %{integer:Event-Timestamp}), \ + acctinterval = %{integer:Event-Timestamp} - \ + UNIX_TIMESTAMP(@acctupdatetime_old), \ + framedipaddress = '%{Framed-IP-Address}', \ + acctsessiontime = '%{Acct-Session-Time}', \ + acctinputoctets = '%{%{Acct-Input-Gigawords}:-0}' \ + << 32 | '%{%{Acct-Input-Octets}:-0}', \ + acctoutputoctets = '%{%{Acct-Output-Gigawords}:-0}' \ + << 32 | '%{%{Acct-Output-Octets}:-0}' \ + WHERE acctsessionid = '%{Acct-Session-Id}' \ + AND username = '%{SQL-User-Name}' \ + AND nasipaddress = '%{NAS-IP-Address}'" + + # + # The update condition matched no existing sessions. Use + # the values provided in the update to create a new session. + # + query = "\ + INSERT INTO ${....acct_table1} \ + (${...column_list}) \ + VALUES \ + ('%{Acct-Session-Id}', \ + '%{Acct-Unique-Session-Id}', \ + '%{SQL-User-Name}', \ + '%{Realm}', \ + '%{NAS-IP-Address}', \ + '%{NAS-Port}', \ + '%{NAS-Port-Type}', \ + FROM_UNIXTIME(%{integer:Event-Timestamp} - \ + %{%{Acct-Session-Time}:-0}), \ + FROM_UNIXTIME(%{integer:Event-Timestamp}), \ + NULL, \ + '%{Acct-Session-Time}', \ + '%{Acct-Authentic}', '', \ + '%{%{Acct-Input-Gigawords}:-0}' << 32 | \ + '%{%{Acct-Input-Octets}:-0}', \ + '%{%{Acct-Output-Gigawords}:-0}' << 32 | \ + '%{%{Acct-Output-Octets}:-0}', \ + '%{Called-Station-Id}', \ + '%{Calling-Station-Id}', \ + '%{Service-Type}', \ + '%{Framed-Protocol}', \ + '%{Framed-IP-Address}')" + } + + stop { + # + # Session has terminated, update the stop time and statistics. + # + query = "\ + UPDATE ${....acct_table2} SET \ + acctstoptime = FROM_UNIXTIME(\ + %{integer:Event-Timestamp}), \ + acctsessiontime = '%{Acct-Session-Time}', \ + acctinputoctets = '%{%{Acct-Input-Gigawords}:-0}' \ + << 32 | '%{%{Acct-Input-Octets}:-0}', \ + acctoutputoctets = '%{%{Acct-Output-Gigawords}:-0}' \ + << 32 | '%{%{Acct-Output-Octets}:-0}', \ + acctterminatecause = '%{Acct-Terminate-Cause}', \ + connectinfo_stop = '%{Connect-Info}' \ + WHERE acctsessionid = '%{Acct-Session-Id}' \ + AND username = '%{SQL-User-Name}' \ + AND nasipaddress = '%{NAS-IP-Address}'" + + # + # The update condition matched no existing sessions. Use + # the values provided in the update to create a new session. + # + query = "\ + INSERT INTO ${....acct_table2} \ + (${...column_list}) \ + VALUES \ + ('%{Acct-Session-Id}', \ + '%{Acct-Unique-Session-Id}', \ + '%{SQL-User-Name}', \ + '%{Realm}', \ + '%{NAS-IP-Address}', \ + '%{NAS-Port}', \ + '%{NAS-Port-Type}', \ + FROM_UNIXTIME(%{integer:Event-Timestamp} - \ + %{%{Acct-Session-Time}:-0}), \ + FROM_UNIXTIME(%{integer:Event-Timestamp}), \ + FROM_UNIXTIME(%{integer:Event-Timestamp}), \ + '%{Acct-Session-Time}', \ + '%{Acct-Authentic}', '', \ + '%{Connect-Info}', \ + '%{%{Acct-Input-Gigawords}:-0}' << 32 | \ + '%{%{Acct-Input-Octets}:-0}', \ + '%{%{Acct-Output-Gigawords}:-0}' << 32 | \ + '%{%{Acct-Output-Octets}:-0}', \ + '%{Called-Station-Id}', \ + '%{Calling-Station-Id}', \ + '%{Acct-Terminate-Cause}', \ + '%{Service-Type}', \ + '%{Framed-Protocol}', \ + '%{Framed-IP-Address}')" + } + } + } + + ####################################################################### + # Authentication Logging Queries + ####################################################################### + # postauth_query - Insert some info after authentication + ####################################################################### + + post-auth { + query = "\ + INSERT INTO ${..postauth_table} \ + (username, pass, reply, authdate) \ + VALUES ( \ + '%{SQL-User-Name}', \ + '%{%{User-Password}:-%{Chap-Password}}', \ + '%{reply:Packet-Type}', \ + '%S')" + } diff --git a/raddb/sql/main/sqlite/schema.sql b/raddb/sql/main/sqlite/schema.sql new file mode 100644 index 00000000000..83a455e620e --- /dev/null +++ b/raddb/sql/main/sqlite/schema.sql @@ -0,0 +1,137 @@ +----------------------------------------------------------------------------- +-- $Id$ -- +-- -- +-- schema.sql rlm_sql - FreeRADIUS SQLite Module -- +-- -- +-- Database schema for SQLite rlm_sql module -- +-- -- +-- To load: -- +-- mysql -uroot -prootpass radius < schema.sql -- +-- -- +----------------------------------------------------------------------------- + +-- +-- Table structure for table 'radacct' +-- +CREATE TABLE radacct ( + radacctid bigint(21) PRIMARY KEY, + acctsessionid varchar(64) NOT NULL default '', + acctuniqueid varchar(32) NOT NULL default '', + username varchar(64) NOT NULL default '', + groupname varchar(64) NOT NULL default '', + realm varchar(64) default '', + nasipaddress varchar(15) NOT NULL default '', + nasportid varchar(15) default NULL, + nasporttype varchar(32) default NULL, + acctstarttime datetime NULL default NULL, + acctupdatetime datetime NULL default NULL, + acctstoptime datetime NULL default NULL, + acctinterval int(12) default NULL, + acctsessiontime int(12) default NULL, + acctauthentic varchar(32) default NULL, + connectinfo_start varchar(50) default NULL, + connectinfo_stop varchar(50) default NULL, + acctinputoctets bigint(20) default NULL, + acctoutputoctets bigint(20) default NULL, + calledstationid varchar(50) NOT NULL default '', + callingstationid varchar(50) NOT NULL default '', + acctterminatecause varchar(32) NOT NULL default '', + servicetype varchar(32) default NULL, + framedprotocol varchar(32) default NULL, + framedipaddress varchar(15) NOT NULL default '' +); + +CREATE UNIQUE INDEX acctuniqueid ON radacct(acctuniqueid); +CREATE INDEX username ON radacct(username); +CREATE INDEX framedipaddress ON radacct (framedipaddress); +CREATE INDEX acctsessionid ON radacct(acctsessionid); +CREATE INDEX acctsessiontime ON radacct(acctsessiontime); +CREATE INDEX acctstarttime ON radacct(acctstarttime); +CREATE INDEX acctinterval ON radacct(acctinterval); +CREATE INDEX acctstoptime ON radacct(acctstoptime); +CREATE INDEX nasipaddress ON radacct(nasipaddress); + +-- +-- Table structure for table 'radcheck' +-- +CREATE TABLE radcheck ( + id int(11) PRIMARY KEY, + username varchar(64) NOT NULL default '', + attribute varchar(64) NOT NULL default '', + op char(2) NOT NULL DEFAULT '==', + value varchar(253) NOT NULL default '' +); +CREATE INDEX check_username ON radcheck(username); + +-- +-- Table structure for table 'radgroupcheck' +-- +CREATE TABLE radgroupcheck ( + id int(11) PRIMARY KEY, + groupname varchar(64) NOT NULL default '', + attribute varchar(64) NOT NULL default '', + op char(2) NOT NULL DEFAULT '==', + value varchar(253) NOT NULL default '' +); +CREATE INDEX check_groupname ON radgroupcheck(groupname); + +-- +-- Table structure for table 'radgroupreply' +-- +CREATE TABLE radgroupreply ( + id int(11) PRIMARY KEY, + groupname varchar(64) NOT NULL default '', + attribute varchar(64) NOT NULL default '', + op char(2) NOT NULL DEFAULT '=', + value varchar(253) NOT NULL default '' +); +CREATE INDEX reply_groupname ON radgroupreply(groupname); + +-- +-- Table structure for table 'radreply' +-- +CREATE TABLE radreply ( + id int(11) PRIMARY KEY, + username varchar(64) NOT NULL default '', + attribute varchar(64) NOT NULL default '', + op char(2) NOT NULL DEFAULT '=', + value varchar(253) NOT NULL default '' +); +CREATE INDEX reply_username ON radreply(username); + +-- +-- Table structure for table 'radusergroup' +-- +CREATE TABLE radusergroup ( + username varchar(64) NOT NULL default '', + groupname varchar(64) NOT NULL default '', + priority int(11) NOT NULL default '1' +); +CREATE INDEX usergroup_username ON radusergroup(username); + +-- +-- Table structure for table 'radpostauth' +-- +CREATE TABLE radpostauth ( + id int(11) PRIMARY KEY, + username varchar(64) NOT NULL default '', + pass varchar(64) NOT NULL default '', + reply varchar(32) NOT NULL default '', + authdate timestamp NOT NULL +); + +-- +-- Table structure for table 'nas' +-- +CREATE TABLE nas ( + id int(11) PRIMARY KEY, + nasname varchar(128) NOT NULL, + shortname varchar(32), + type varchar(30) DEFAULT 'other', + ports int(5), + secret varchar(60) DEFAULT 'secret' NOT NULL, + server varchar(64), + community varchar(50), + description varchar(200) DEFAULT 'RADIUS Client' +); +CREATE INDEX nasname ON nas(nasname); diff --git a/raddb/sql/main/sqlite/setup.sql b/raddb/sql/main/sqlite/setup.sql new file mode 100755 index 00000000000..2c1d69be338 --- /dev/null +++ b/raddb/sql/main/sqlite/setup.sql @@ -0,0 +1,24 @@ +# -*- text -*- +## +## admin.sql -- MySQL commands for creating the RADIUS user. +## +## WARNING: You should change 'localhost' and 'radpass' +## to something else. Also update raddb/sql.conf +## with the new RADIUS password. +## +## $Id$ + +# +# Create default administrator for RADIUS +# +CREATE USER 'radius'@'localhost'; +SET PASSWORD FOR 'radius'@'localhost' = PASSWORD('radpass'); + +# The server can read any table in SQL +GRANT SELECT ON radius.* 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';