diff options
Diffstat (limited to 'raddb/mods-config/sql/ippool/mssql')
-rw-r--r-- | raddb/mods-config/sql/ippool/mssql/procedure.sql | 137 | ||||
-rw-r--r-- | raddb/mods-config/sql/ippool/mssql/queries.conf | 175 | ||||
-rw-r--r-- | raddb/mods-config/sql/ippool/mssql/schema.sql | 25 |
3 files changed, 337 insertions, 0 deletions
diff --git a/raddb/mods-config/sql/ippool/mssql/procedure.sql b/raddb/mods-config/sql/ippool/mssql/procedure.sql new file mode 100644 index 0000000..5c621fb --- /dev/null +++ b/raddb/mods-config/sql/ippool/mssql/procedure.sql @@ -0,0 +1,137 @@ +-- +-- A stored procedure to reallocate a user's previous address, otherwise +-- provide a free address. +-- +-- Using this SP reduces the usual set dialogue of queries to a single +-- query: +-- +-- BEGIN TRAN; "SELECT FOR UPDATE"; UPDATE; COMMIT TRAN; -> EXEC sp +-- +-- The stored procedure is executed on an database instance within a single +-- round trip which often leads to reduced deadlocking and significant +-- performance improvements especially on multi-master clusters, perhaps even +-- by an order of magnitude or more. +-- +-- To use this stored procedure the corresponding queries.conf statements must +-- be configured as follows: +-- +-- allocate_begin = "" +-- allocate_find = "\ +-- EXEC fr_allocate_previous_or_new_framedipaddress \ +-- @v_pool_name = '%{control:${pool_name}}', \ +-- @v_username = '%{User-Name}', \ +-- @v_callingstationid = '%{Calling-Station-Id}', \ +-- @v_nasipaddress = '%{NAS-IP-Address}', \ +-- @v_pool_key = '${pool_key}', \ +-- @v_lease_duration = ${lease_duration} \ +-- " +-- allocate_update = "" +-- allocate_commit = "" +-- + +CREATE INDEX UserName_CallingStationId ON radippool(pool_name,UserName,CallingStationId) +GO + +CREATE OR ALTER PROCEDURE fr_allocate_previous_or_new_framedipaddress + @v_pool_name VARCHAR(64), + @v_username VARCHAR(64), + @v_callingstationid VARCHAR(64), + @v_nasipaddress VARCHAR(15), + @v_pool_key VARCHAR(64), + @v_lease_duration INT +AS + BEGIN + + -- MS SQL lacks a "SELECT FOR UPDATE" statement, and its table + -- hints do not provide a direct means to implement the row-level + -- read lock needed to guarentee that concurrent queries do not + -- select the same Framed-IP-Address for allocation to distinct + -- users. + -- + -- The "WITH cte AS ( SELECT ... ) UPDATE cte ... OUTPUT INTO" + -- patterns in this procedure body compensate by wrapping + -- the SELECT in a synthetic UPDATE which locks the row. + + DECLARE @r_address_tab TABLE(id VARCHAR(15)); + DECLARE @r_address VARCHAR(15); + + BEGIN TRAN; + + -- Reissue an existing IP address lease when re-authenticating a session + -- + WITH cte AS ( + SELECT TOP(1) FramedIPAddress + FROM radippool WITH (xlock rowlock readpast) + WHERE pool_name = @v_pool_name + AND expiry_time > CURRENT_TIMESTAMP + AND NASIPAddress = @v_nasipaddress AND pool_key = @v_pool_key + ) + UPDATE cte + SET FramedIPAddress = FramedIPAddress + OUTPUT INSERTED.FramedIPAddress INTO @r_address_tab; + SELECT @r_address = id FROM @r_address_tab; + + -- Reissue an user's previous IP address, provided that the lease is + -- available (i.e. enable sticky IPs) + -- + -- When using this SELECT you should delete the one above. You must also + -- set allocate_clear = "" in queries.conf to persist the associations + -- for expired leases. + -- + -- WITH cte AS ( + -- SELECT TOP(1) FramedIPAddress + -- FROM radippool WITH (xlock rowlock readpast) + -- WHERE pool_name = @v_pool_name + -- AND NASIPAddress = @v_nasipaddress AND pool_key = @v_pool_key + -- ) + -- UPDATE cte + -- SET FramedIPAddress = FramedIPAddress + -- OUTPUT INSERTED.FramedIPAddress INTO @r_address_tab; + -- SELECT @r_address = id FROM @r_address_tab; + + -- If we didn't reallocate a previous address then pick the least + -- recently used address from the pool which maximises the likelihood + -- of re-assigning the other addresses to their recent user + -- + IF @r_address IS NULL + BEGIN + WITH cte AS ( + SELECT TOP(1) FramedIPAddress + FROM radippool WITH (xlock rowlock readpast) + WHERE pool_name = @v_pool_name + AND expiry_time < CURRENT_TIMESTAMP + ORDER BY + expiry_time + ) + UPDATE cte + SET FramedIPAddress = FramedIPAddress + OUTPUT INSERTED.FramedIPAddress INTO @r_address_tab; + SELECT @r_address = id FROM @r_address_tab; + END + + -- Return nothing if we failed to allocated an address + -- + IF @r_address IS NULL + BEGIN + COMMIT TRAN; + RETURN; + END + + -- Update the pool having allocated an IP address + -- + UPDATE radippool + SET + NASIPAddress = @v_nasipaddress, + pool_key = @v_pool_key, + CallingStationId = @v_callingstationid, + UserName = @v_username, + expiry_time = DATEADD(SECOND,@v_lease_duration,CURRENT_TIMESTAMP) + WHERE framedipaddress = @r_address; + + COMMIT TRAN; + + -- Return the address that we allocated + SELECT @r_address; + + END +GO diff --git a/raddb/mods-config/sql/ippool/mssql/queries.conf b/raddb/mods-config/sql/ippool/mssql/queries.conf new file mode 100644 index 0000000..8105dcc --- /dev/null +++ b/raddb/mods-config/sql/ippool/mssql/queries.conf @@ -0,0 +1,175 @@ +# -*- text -*- +# +# ippool/mssql/queries.conf -- MSSQL queries for rlm_sqlippool +# +# $Id$ + +# +# MSSQL-specific syntax - required if finding the address and updating +# it are separate queries +# +#allocate_begin = "BEGIN TRAN" +#allocate_commit = "COMMIT TRAN" + +allocate_begin = "" +allocate_commit = "" + +# +# This series of queries allocates an IP address +# + +# +# Attempt to allocate the address a client previously had. This is based on pool_key +# and nasipaddress. Change the criteria if the identifier for "stickyness" is different. +# If different criteria are used, check the indexes on the IP pool table to ensure the fields +# are appropriately indexed. To disable stickyness comment out this query. +# +allocate_existing = "\ + WITH cte AS ( \ + SELECT TOP(1) FramedIPAddress, CallingStationId, UserName, expiry_time \ + FROM ${ippool_table} WITH (xlock rowlock readpast) \ + WHERE pool_name = '%{control:${pool_name}}' \ + AND NASIPAddress = '%{NAS-IP-Address}' AND pool_key = '${pool_key}' \ + ORDER BY expiry_time DESC \ + ) \ + UPDATE cte \ + SET \ + CallingStationId = '%{Calling-Station-Id}', \ + UserName = '%{User-Name}', expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ + OUTPUT INSERTED.FramedIPAddress" + +# +# Find a free IP address from the pool, choosing the oldest expired one. +# +allocate_find = "\ + WITH cte AS ( \ + SELECT TOP(1) FramedIPAddress, NASIPAddress, pool_key, \ + CallingStationId, UserName, expiry_time \ + FROM ${ippool_table} WITH (xlock rowlock readpast) \ + WHERE pool_name = '%{control:${pool_name}}' \ + AND expiry_time < CURRENT_TIMESTAMP \ + ORDER BY expiry_time \ + ) \ + UPDATE cte \ + SET \ + NASIPAddress = '%{NAS-IP-Address}', pool_key = '${pool_key}', \ + CallingStationId = '%{Calling-Station-Id}', \ + UserName = '%{User-Name}', expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ + OUTPUT INSERTED.FramedIPAddress" + +# +# If you prefer to allocate a random IP address every time, use this query instead. +# Note: This is very slow if you have a lot of free IPs. +# +#allocate_find = "\ +# WITH cte AS ( \ +# SELECT TOP(1) FramedIPAddress, NASIPAddress, pool_key, \ +# CallingStationId, UserName, expiry_time \ +# FROM ${ippool_table} \ +# WHERE pool_name = '%{control:${pool_name}}' \ +# AND expiry_time < CURRENT_TIMESTAMP \ +# ORDER BY newid() \ +# ) \ +# UPDATE cte WITH (rowlock, readpast) \ +# SET \ +# NASIPAddress = '%{NAS-IP-Address}', pool_key = '${pool_key}', \ +# CallingStationId = '%{Calling-Station-Id}', \ +# UserName = '%{User-Name}', expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ +# OUTPUT INSERTED.FramedIPAddress" + +# +# If an IP could not be allocated, check to see if the pool exists or not +# This allows the module to differentiate between a full pool and no pool +# Note: If you are not running redundant pool modules this query may be +# commented out to save running this query every time an ip is not allocated. +# +pool_check = "\ + SELECT TOP(1) id \ + FROM ${ippool_table} \ + WHERE pool_name='%{control:${pool_name}}'" + +# +# This is the final IP Allocation query, which saves the allocated ip details. +# Only needed if allocate_existing / allocate_find do not also update the pool. +# +#allocate_update = "\ +# UPDATE ${ippool_table} \ +# SET \ +# NASIPAddress = '%{NAS-IP-Address}', pool_key = '${pool_key}', \ +# CallingStationId = '%{Calling-Station-Id}', \ +# UserName = '%{User-Name}', expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ +# WHERE FramedIPAddress = '%I'" + +# +# Use a stored procedure to find AND allocate the address. Read and customise +# `procedure.sql` in this directory to determine the optimal configuration. +# +#allocate_begin = "" +#allocate_find = "\ +# EXEC fr_allocate_previous_or_new_framedipaddress \ +# @v_pool_name = '%{control:${pool_name}}', \ +# @v_username = '%{User-Name}', \ +# @v_callingstationid = '%{Calling-Station-Id}', \ +# @v_nasipaddress = '%{NAS-IP-Address}', \ +# @v_pool_key = '${pool_key}', \ +# @v_lease_duration = ${lease_duration} \ +# " +#allocate_update = "" +#allocate_commit = "" + +# +# This series of queries frees an IP number when an accounting START record arrives. +# +start_update = "\ + UPDATE ${ippool_table} \ + SET \ + expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ + WHERE NASIPAddress = '%{NAS-IP-Address}' \ + AND pool_key = '${pool_key}' \ + AND UserName = '%{User-Name}' \ + AND CallingStationId = '%{Calling-Station-Id}' \ + AND FramedIPAddress = '%{${attribute_name}}'" + +# +# Expire an IP when an accounting STOP record arrives +# +stop_clear = "\ + UPDATE ${ippool_table} \ + SET \ + expiry_time = CURRENT_TIMESTAMP \ + WHERE NASIPAddress = '%{%{Nas-IP-Address}:-%{Nas-IPv6-Address}}' \ + AND pool_key = '${pool_key}' \ + AND UserName = '%{User-Name}' \ + AND CallingStationId = '%{Calling-Station-Id}' \ + AND FramedIPAddress = '%{${attribute_name}}'" + +# +# Update the expiry time for an IP when an accounting ALIVE record arrives +# +alive_update = "\ + UPDATE ${ippool_table} \ + SET \ + expiry_time = DATEADD(SECOND,${lease_duration},CURRENT_TIMESTAMP) \ + WHERE NASIPAddress = '%{%{Nas-IP-Address}:-%{Nas-IPv6-Address}}' \ + AND pool_key = '${pool_key}' \ + AND UserName = '%{User-Name}' \ + AND CallingStationId = '%{Calling-Station-Id}' \ + AND FramedIPAddress = '%{${attribute_name}}'" + +# +# Expires all IPs allocated to a NAS when an accounting ON record arrives +# +on_clear = "\ + UPDATE ${ippool_table} \ + SET \ + expiry_time = CURRENT_TIMESTAMP \ + WHERE NASIPAddress = '%{%{Nas-IP-Address}:-%{Nas-IPv6-Address}}'" + +# +# Expires all IPs allocated to a NAS when an accounting OFF record arrives +# +off_clear = "\ + UPDATE ${ippool_table} \ + SET \ + expiry_time = CURRENT_TIMESTAMP \ + WHERE NASIPAddress = '%{%{Nas-IP-Address}:-%{Nas-IPv6-Address}}'" diff --git a/raddb/mods-config/sql/ippool/mssql/schema.sql b/raddb/mods-config/sql/ippool/mssql/schema.sql new file mode 100644 index 0000000..d4bff44 --- /dev/null +++ b/raddb/mods-config/sql/ippool/mssql/schema.sql @@ -0,0 +1,25 @@ +-- +-- Table structure for table 'radippool' +-- +CREATE TABLE radippool ( + id int IDENTITY (1,1) NOT NULL, + pool_name varchar(30) NOT NULL, + FramedIPAddress varchar(15) NOT NULL default '', + NASIPAddress varchar(15) NOT NULL default '', + CalledStationId VARCHAR(32) NOT NULL default '', + CallingStationId VARCHAR(30) NOT NULL default '', + expiry_time DATETIME NOT NULL default CURRENT_TIMESTAMP, + UserName varchar(64) NOT NULL default '', + pool_key varchar(30) NOT NULL default '', + PRIMARY KEY (id) +) +GO + +CREATE INDEX poolname_expire ON radippool(pool_name, expiry_time) +GO + +CREATE INDEX FramedIPAddress ON radippool(FramedIPAddress) +GO + +CREATE INDEX NASIPAddress_poolkey_FramedIPAddress ON radippool(NASIPAddress, pool_key, FramedIPAddress) +GO |