Работоспособная конфигурация FreeRadius2 с MS SQL
Удивительно, но нигде в интернете я не нашел примера конфигурации FreeRadius 2 c MS SQL. Пришлось написать.
Инсталляция ПО для CentOS
yum install freeradius2 freeradius2-unixODBC freetds unixODBC
Конфигурация FreeRadius2
Добавляем /etc/freetds.conf:
[server name]
host = ip/hostname
port = 1433
tds version = 8.0
Делаем файл - шаблон конфигурации драйвера:
[TDS]
Description = FreeTDS with protocol v8.0
Driver = /usr/lib64/libtdsodbc.so.0
Устанавливаем драйвер:
odbcinst -i -d -f шаблон_конфигурации_драйвера
Делаем файл - шаблон конфигурации источника данных:
[server name]
Driver = TDS
Description = Radius database
Trace = No
Servername = server_name
Database = database_name
UID = sql_login
PWD = sql_password
Устанавливаем его как системный (это важно!) источник данных:
odbcinst -i -s -l -f шаблон_конфигурации_источника_данных
Вот мой минимально работоспособный /etc/raddb/sql.conf:
##
## sql.conf -- SQL modules
##
## $Id$
sql {
#
# Set the database to one of:
#
# mysql, mssql, oracle, postgresql
#
database = "mssql"
#
# Which FreeRADIUS driver to use.
#
driver = "rlm_sql_unixodbc"
# Connection info:
server = "server_name"
login = "sql_login"
password = "sql_password"
# Database table configuration for everything except Oracle
radius_db = "database_name"
# If you want both stop and start records logged to the
# same SQL table, leave this as is. If you want them in
# different tables, put the start table in acct_table1
# and stop table in acct_table2
acct_table1 = "radacct"
acct_table2 = "radacct"
# Allow for storing data after authentication
postauth_table = "radpostauth"
authcheck_table = "radcheck"
authreply_table = "radreply"
groupcheck_table = "radgroupcheck"
groupreply_table = "radgroupreply"
# Table to keep group info
usergroup_table = "radusergroup"
# If set to 'yes' (default) we read the group tables
# If set to 'no' the user MUST have Fall-Through = Yes in the radreply table
# read_groups = yes
# Remove stale session if checkrad does not see a double login
deletestalesessions = yes
# Print all SQL statements when in debug mode (-x)
sqltrace = no
sqltracefile = ${logdir}/sqltrace.sql
# number of sql connections to make to server
num_sql_socks = 5
# number of seconds to dely retrying on a failed database
# connection (per_socket)
connect_failure_retry_delay = 60
# lifetime of an SQL socket. If you are having network issues
# such as TCP sessions expiring, you may need to set the socket
# lifetime. If set to non-zero, any open connections will be
# closed "lifetime" seconds after they were first opened.
lifetime = 0
# Maximum number of queries used by an SQL socket. If you are
# having issues with SQL sockets lasting "too long", you can
# limit the number of queries performed over one socket. After
# "max_qeuries", the socket will be closed. Use 0 for "no limit".
max_queries = 0
# Set to 'yes' to read radius clients from the database ('nas' table)
# Clients will ONLY be read on server startup. For performance
# and security reasons, finding clients via SQL queries CANNOT
# be done "live" while the server is running.
#
#readclients = yes
# Table to keep radius client info
#nas_table = "nas"
# Read driver-specific configuration
$INCLUDE sql/${database}/queries.conf
}
Конфигурация БД MS SQL
-- структура БД
CREATE TABLE [dbo].[radacct] (
[RadAcctId] BIGINT IDENTITY (1, 1) NOT NULL ,
[AcctSessionId] VARCHAR (64) NOT NULL ,
[AcctUniqueId] VARCHAR (32) NOT NULL ,
[UserName] VARCHAR (253) ,
[GroupName] VARCHAR (253) ,
[Realm] VARCHAR (64) ,
[NASIPAddress] VARCHAR (15) NOT NULL ,
[NASPortId] VARCHAR (15) ,
[NASPortType] VARCHAR (32) ,
[AcctStartTime] DATETIME2 ,
[AcctStopTime] DATETIME2 ,
[AcctSessionTime] BIGINT ,
[AcctAuthentic] VARCHAR (32) ,
[ConnectInfo_start] VARCHAR (50) ,
[ConnectInfo_stop] VARCHAR (50) ,
[AcctInputOctets] BIGINT ,
[AcctOutputOctets] BIGINT ,
[CalledStationId] VARCHAR (50) ,
[CallingStationId] VARCHAR (50) ,
[AcctTerminateCause] VARCHAR (32) ,
[ServiceType] VARCHAR (32) ,
[XAscendSessionSvrKey] VARCHAR (10) ,
[FramedProtocol] VARCHAR (32) ,
[FramedIPAddress] VARCHAR (15) ,
[AcctStartDelay] INT ,
[AcctStopDelay] INT,
CONSTRAINT [PK_radacct] PRIMARY KEY CLUSTERED ( [RadAcctId] )
) ON [PRIMARY]
GO
CREATE INDEX [IX_radacct_active_user] ON [dbo].[radacct] (UserName, NASIPAddress, AcctSessionId) WHERE AcctStopTime IS NULL ON [PRIMARY]
GO
CREATE INDEX [IX_radacct_start_user] ON [dbo].[radacct] (AcctStartTime, UserName) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radcheck] (
[id] INT IDENTITY (1, 1) NOT NULL ,
[UserName] VARCHAR (64) NOT NULL DEFAULT '',
[Attribute] VARCHAR (64) NOT NULL DEFAULT '',
[op] CHAR (2) NOT NULL DEFAULT '==',
[Value] VARCHAR (253) NOT NULL DEFAULT '',
CONSTRAINT [PK_radcheck] PRIMARY KEY CLUSTERED ( [id] )
) ON [PRIMARY]
GO
CREATE INDEX [IX_radcheck] ON [dbo].[radcheck]([UserName]) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radgroupcheck] (
[id] INT IDENTITY (1, 1) NOT NULL ,
[GroupName] VARCHAR (64) NOT NULL DEFAULT '',
[Attribute] VARCHAR (64) NOT NULL DEFAULT '',
[op] CHAR (2) NOT NULL DEFAULT '==',
[Value] VARCHAR (253) NOT NULL DEFAULT '',
CONSTRAINT [PK_radgroupcheck] PRIMARY KEY CLUSTERED ([id])
) ON [PRIMARY]
GO
CREATE INDEX [IX_radgroupcheck] ON [dbo].[radgroupcheck]([GroupName]) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radgroupreply] (
[id] INT IDENTITY (1, 1) NOT NULL ,
[GroupName] VARCHAR (64) NOT NULL DEFAULT '',
[Attribute] VARCHAR (64) NOT NULL DEFAULT '',
[op] CHAR (2) NOT NULL DEFAULT '=',
[Value] VARCHAR (253) NOT NULL DEFAULT '',
CONSTRAINT [PK_radgroupreply] PRIMARY KEY CLUSTERED ([id])
) ON [PRIMARY]
GO
CREATE INDEX [IX_radgroupreply] ON [dbo].[radgroupreply]([GroupName]) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radreply] (
[id] INT IDENTITY (1, 1) NOT NULL ,
[UserName] VARCHAR (64) NOT NULL DEFAULT '',
[Attribute] VARCHAR (64) NOT NULL DEFAULT '',
[op] CHAR (2) NOT NULL DEFAULT '=',
[Value] VARCHAR (253) NOT NULL DEFAULT '',
CONSTRAINT [PK_radreply] PRIMARY KEY CLUSTERED ([id])
) ON [PRIMARY]
GO
CREATE INDEX [IX_radreply] ON [dbo].[radreply]([UserName]) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radusergroup] (
[UserName] VARCHAR (64) NOT NULL DEFAULT '',
[GroupName] VARCHAR (64) NOT NULL DEFAULT ''
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[radpostauth] (
[id] INT IDENTITY (1, 1) NOT NULL ,
[username] VARCHAR (253) NOT NULL ,
[pass] VARCHAR (128) ,
reply VARCHAR (32) ,
CalledStationId VARCHAR(50) ,
CallingStationId VARCHAR(50) ,
authdate DATETIME2 NOT NULL DEFAULT CURRENT_TIMESTAMP,
) ON [PRIMARY]
GO
-- тестовые данные
INSERT INTO radcheck VALUES ('test123', 'User-Password', ':=', '12345');
INSERT INTO radgroupcheck VALUES ('group', 'Auth-Type', '=', 'PAP');
INSERT INTO radgroupreply VALUES ('testgroup', 'Framed-IP-Address', '=', '10.0.1.0');
INSERT INTO radgroupreply VALUES ('testgroup', 'Framed-IP-Netmask', '=', '255.255.255.0');
INSERT INTO radgroupreply VALUES ('group', 'Framed-IP-Address', '=', '192.168.0.0');
--INSERT INTO radgroupreply VALUES ('group', 'Framed-Compression', '=', 'no');
INSERT INTO radgroupreply VALUES ('group', 'Session-Timeout', '=', '0');
INSERT INTO radgroupreply VALUES ('group', 'Idle-Timeout', '=', '0');
INSERT INTO radgroupreply VALUES ('group', 'Port-Limit', '=', '0');
INSERT INTO radgroupreply VALUES ('group', 'Framed-IP-Netmask', '=', '255.255.255.0');
INSERT INTO radreply VALUES ('test123', 'Framed-IP-Address', '=', '10.0.77.17');
--INSERT INTO radreply VALUES ('test123', 'Framed-Compression', '=', 'no');
INSERT INTO radusergroup VALUES ('test123', 'group');
Создаем папку /etc/raddb/sql/mssql и в ней файл queries.conf, в котором будут лежать все запросы к БД:
# Safe characters list for sql queries. Everything else is replaced
# with their mime-encoded equivalents.
# The default list should be ok
# safe-characters = "@abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789.-_: /"
#######################################################################
# 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 "none" as the user name.
#
#sql_user_name = "%{%{Stripped-User-Name}:-%{%{User-Name}:-none}}"
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
#######################################################################
#nas_query = "SELECT id, nasname, shortname, type, secret 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 insensitive usernames. WARNING: Slower queries!
# authorize_check_query = "SELECT id, UserName, Attribute, Value, Op \
# FROM ${authcheck_table} \
# WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}') \
# ORDER BY id"
# authorize_reply_query = "SELECT id, UserName, Attribute, Value, Op \
# FROM ${authreply_table} \
# WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}') \
# ORDER BY id"
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 insensitive usernames. WARNING: Slower queries!
# authorize_group_check_query = "SELECT ${groupcheck_table}.id, ${groupcheck_table}.GroupName, \
# ${groupcheck_table}.Attribute, ${groupcheck_table}.Value, ${groupcheck_table}.Op \
# FROM ${groupcheck_table}, ${usergroup_table} \
# WHERE LOWER(${usergroup_table}.UserName) = LOWER('%{SQL-User-Name}') AND ${usergroup_table}.GroupName = ${groupcheck_table}.GroupName \
# ORDER BY ${groupcheck_table}.id"
# authorize_group_reply_query = "SELECT ${groupreply_table}.id, ${groupreply_table}.GroupName, \
# ${groupreply_table}.Attribute, ${groupreply_table}.Value, ${groupreply_table}.Op \
# FROM ${groupreply_table}, ${usergroup_table} \
# WHERE LOWER(${usergroup_table}.UserName) = LOWER('%{SQL-User-Name}') AND ${usergroup_table}.GroupName = ${groupreply_table}.GroupName \
# ORDER BY ${groupreply_table}.id"
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 simultaneous 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 Queries
#######################################################################
# accounting_onoff_query - query for Accounting On/Off packets
# accounting_update_query - query for Accounting update packets
# accounting_update_query_alt - query for Accounting update packets
# (alternate in case first query fails)
# accounting_start_query - query for Accounting start packets
# accounting_start_query_alt - query for Accounting start packets
# (alternate in case first query fails)
# accounting_stop_query - query for Accounting stop packets
# accounting_stop_query_alt - query for Accounting start packets
# (alternate in case first query doesn't
# affect any existing rows in the table)
#######################################################################
accounting_onoff_query = "UPDATE ${acct_table1} \
SET AcctStopTime = DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)), \
AcctSessionTime = DATEDIFF(SECOND, AcctStartTime, DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2))), \
AcctTerminateCause = '%{Acct-Terminate-Cause}', \
AcctStopDelay = 0 \
WHERE AcctStopTime IS NULL \
AND NASIPAddress= '%{NAS-IP-Address}' \
AND AcctStartTime <= CAST('%S' AS datetime2)"
accounting_update_query = "UPDATE ${acct_table1} \
SET FramedIPAddress = NULLIF('%{Framed-IP-Address}', ''), \
AcctSessionTime = '%{Acct-Session-Time}', \
AcctInputOctets = ((%{%{Acct-Input-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Input-Octets}:-0}), \
AcctOutputOctets = ((%{%{Acct-Output-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Output-Octets}:-0}) \
WHERE AcctSessionId = '%{Acct-Session-Id}' AND UserName = '%{SQL-User-Name}' \
AND NASIPAddress= '%{NAS-IP-Address}' AND AcctStopTime IS NULL"
accounting_update_query_alt = "INSERT INTO ${acct_table1} \
(AcctSessionId, AcctUniqueId, UserName, Realm, NASIPAddress, \
NASPortId, NASPortType, AcctStartTime, \
AcctSessionTime, AcctAuthentic, AcctInputOctets, \
AcctOutputOctets, CalledStationId, CallingStationId, \
ServiceType, FramedProtocol, FramedIPAddress, XAscendSessionSvrKey) \
VALUES('%{Acct-Session-Id}', '%{Acct-Unique-Session-Id}', \
'%{SQL-User-Name}', NULLIF('%{Realm}', ''), '%{NAS-IP-Address}', \
'%{%{NAS-Port}:-NULL}', '%{NAS-Port-Type}', \
DATEADD(SECOND,-1*(%{%{Acct-Delay-Time}:-0}+%{%{Acct-Session-Time}:-0}),CAST('%S' AS datetime2)), \
'%{Acct-Session-Time}', '%{Acct-Authentic}', \
(('%{%{Acct-Input-Gigawords}:-0}' * POWER(2, 32)) + '%{%{Acct-Input-Octets}:-0}'), \
(('%{%{Acct-Output-Gigawords}:-0}' * POWER(2, 32)) + '%{%{Acct-Output-Octets}:-0}'), \
'%{Called-Station-Id}', \
'%{Calling-Station-Id}', '%{Service-Type}', '%{Framed-Protocol}', \
NULLIF('%{Framed-IP-Address}', ''), '%{X-Ascend-Session-Svr-Key}')"
accounting_start_query = "INSERT INTO ${acct_table1} \
(AcctSessionId, AcctUniqueId, UserName, Realm, NASIPAddress, \
NASPortId, NASPortType, AcctStartTime, AcctAuthentic, \
ConnectInfo_start, CalledStationId, CallingStationId, ServiceType, \
FramedProtocol, FramedIPAddress, AcctStartDelay, XAscendSessionSvrKey) \
VALUES('%{Acct-Session-Id}', \
'%{Acct-Unique-Session-Id}', \
'%{SQL-User-Name}', \
NULLIF('%{Realm}', ''), \
'%{NAS-IP-Address}', \
'%{%{NAS-Port}:-NULL}', \
'%{NAS-Port-Type}', \
DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)), \
'%{Acct-Authentic}', \
'%{Connect-Info}', \
'%{Called-Station-Id}', \
'%{Calling-Station-Id}', \
'%{Service-Type}', \
'%{Framed-Protocol}', \
NULLIF('%{Framed-IP-Address}', ''), \
0, \
'%{X-Ascend-Session-Svr-Key}')"
accounting_start_query_alt = "UPDATE ${acct_table1} \
SET AcctStartTime = DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)), \
AcctStartDelay = 0, \
ConnectInfo_start = '%{Connect-Info}' \
WHERE AcctSessionId = '%{Acct-Session-Id}' \
AND UserName = '%{SQL-User-Name}' \
AND NASIPAddress = '%{NAS-IP-Address}' \
AND AcctStopTime IS NULL"
accounting_stop_query = "UPDATE ${acct_table2} \
SET AcctStopTime = DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)), \
AcctSessionTime = CASE WHEN '%{Acct-Session-Time}' = '' THEN \
DATEDIFF(SECOND, AcctStartTime, DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)))\
ELSE '%{Acct-Session-Time}' END, \
AcctInputOctets = ((%{%{Acct-Input-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Input-Octets}:-0}), \
AcctOutputOctets = ((%{%{Acct-Output-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Output-Octets}:-0}), \
AcctTerminateCause = '%{Acct-Terminate-Cause}', \
AcctStopDelay = 0, \
FramedIPAddress = NULLIF('%{Framed-IP-Address}', ''), \
ConnectInfo_stop = '%{Connect-Info}' \
WHERE AcctSessionId = '%{Acct-Session-Id}' \
AND UserName = '%{SQL-User-Name}' \
AND NASIPAddress = '%{NAS-IP-Address}' \
AND AcctStopTime IS NULL"
accounting_stop_query_alt = "INSERT INTO ${acct_table2} \
(AcctSessionId, AcctUniqueId, UserName, Realm, NASIPAddress, NASPortId, NASPortType, AcctStartTime, AcctStopTime, \
AcctSessionTime, AcctAuthentic, ConnectInfo_stop, AcctInputOctets, AcctOutputOctets, CalledStationId, \
CallingStationId, AcctTerminateCause, ServiceType, FramedProtocol, FramedIPAddress, AcctStopDelay) \
values('%{Acct-Session-Id}', \
'%{Acct-Unique-Session-Id}', \
'%{SQL-User-Name}', \
NULLIF('%{Realm}', ''), \
'%{NAS-IP-Address}', \
%{%{NAS-Port}:-NULL}, \
'%{NAS-Port-Type}', \
DATEADD(SECOND,-1*(%{%{Acct-Delay-Time}:-0}+%{%{Acct-Session-Time}:-0}),CAST('%S' AS datetime2)), \
DATEADD(SECOND,-1*%{%{Acct-Delay-Time}:-0},CAST('%S' AS datetime2)), \
NULLIF('%{Acct-Session-Time}', NULL), '%{Acct-Authentic}', \
'%{Connect-Info}', \
((%{%{Acct-Input-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Input-Octets}:-0}), \
((%{%{Acct-Output-Gigawords}:-0} * POWER(2, 32)) + %{%{Acct-Output-Octets}:-0}), \
'%{Called-Station-Id}', \
'%{Calling-Station-Id}', \
'%{Acct-Terminate-Cause}', \
'%{Service-Type}', \
'%{Framed-Protocol}', \
NULLIF('%{Framed-IP-Address}', ''), 0)"
#######################################################################
# Group Membership Queries
#######################################################################
# group_membership_query - Check user group membership
#######################################################################
# Use these for case insensitive usernames. WARNING: Slower queries!
# group_membership_query = "SELECT GroupName FROM ${usergroup_table} WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}')"
group_membership_query = "SELECT GroupName FROM ${usergroup_table} WHERE UserName='%{SQL-User-Name}'"
#######################################################################
# Authentication Logging Queries
#######################################################################
# postauth_query - Insert some info after authentication
#######################################################################
postauth_query = "INSERT INTO ${postauth_table} (username, pass, reply, authdate) \
VALUES ('%{User-Name}', '%{%{User-Password}:-Chap-Password}', '%{reply:Packet-Type}', CURRENT_TIMESTAMP)"
Пробный запуск
Не забудьте поправить clients.conf, чтоб разрешить доступ к RADIUS-у со своей машины или NAS-а, и поправить radius.conf, где раскомментировать $INCLUDE sql.conf.
Запускаем radiusd -X и находим строки, где выполняется подключение SQL, убеждаемся, что нет ошибок с подключением. Иначе, используем tsql и isql для диагностики конфигурации FreeTDS и unixODBC.
Когда с подключением все в порядке, можете использовать какую-нибудь утилиту для тестирования RADIUS сервера, например NTRadPing. Пользователь для пробы - test123, пароль 12345.