]> git.ipfire.org Git - thirdparty/freeradius-server.git/commitdiff
MySQL sqlippools: Find and allocate stored procedure 3048/head
authorTerry Burton <tez@terryburton.co.uk>
Mon, 14 Oct 2019 22:09:09 +0000 (23:09 +0100)
committerTerry Burton <tez@terryburton.co.uk>
Tue, 15 Oct 2019 11:03:14 +0000 (12:03 +0100)
raddb/mods-config/sql/ippool/mysql/procedure.sql [new file with mode: 0644]
raddb/mods-config/sql/ippool/mysql/queries.conf

diff --git a/raddb/mods-config/sql/ippool/mysql/procedure.sql b/raddb/mods-config/sql/ippool/mysql/procedure.sql
new file mode 100644 (file)
index 0000000..291b11c
--- /dev/null
@@ -0,0 +1,121 @@
+--
+-- 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:
+--
+--   START TRANSACTION; SELECT FOR UPDATE; UPDATE; COMMIT;  ->  CALL 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 = "\
+--     CALL sp_allocate_previous_or_new_framedipaddress( \
+--             '%{control:${pool_name}}', \
+--             '%{User-Name}', \
+--             '%{Calling-Station-Id}', \
+--             '%{NAS-IP-Address}', \
+--             '${pool_key}', \
+--             ${lease_duration} \
+--     )"
+-- allocate_update = ""
+-- allocate_commit = ""
+--
+
+CREATE INDEX poolname_username_callingstationid ON radippool(pool_name,username,callingstationid);
+
+DELIMITER $$
+
+DROP PROCEDURE IF EXISTS sp_allocate_previous_or_new_framedipaddress;
+CREATE PROCEDURE sp_allocate_previous_or_new_framedipaddress (
+        IN v_pool_name VARCHAR(64),
+        IN v_username VARCHAR(64),
+        IN v_callingstationid VARCHAR(64),
+        IN v_nasipaddress VARCHAR(15),
+        IN v_pool_key VARCHAR(64),
+        IN v_lease_duration INT
+)
+proc:BEGIN
+        DECLARE r_address VARCHAR(15);
+
+        SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
+
+        START TRANSACTION;
+
+        -- Reissue an existing IP address lease when re-authenticating a session
+        --
+        SELECT framedipaddress INTO r_address
+        FROM radippool
+        WHERE pool_name = v_pool_name
+                AND expiry_time > NOW()
+                AND username = v_username
+                AND callingstationid = v_callingstationid
+        LIMIT 1
+        FOR UPDATE;
+--      FOR UPDATE SKIP LOCKED;  -- Better performance, but limited support
+
+        -- 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.
+        --
+        -- SELECT framedipaddress INTO r_address
+        -- FROM radippool
+        -- WHERE pool_name = v_pool_name
+        --         AND username = v_username
+        --         AND callingstationid = v_callingstationid
+        -- LIMIT 1
+        -- FOR UPDATE;
+        -- -- FOR UPDATE SKIP LOCKED;  -- Better performance, but limited support
+
+        -- 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 THEN
+                SELECT framedipaddress INTO r_address
+                FROM radippool
+                WHERE pool_name = v_pool_name
+                        AND ( expiry_time < NOW() OR expiry_time IS NULL )
+                ORDER BY
+                        expiry_time
+                LIMIT 1
+                FOR UPDATE;
+--              FOR UPDATE SKIP LOCKED;  -- Better performance, but limited support
+        END IF;
+
+        -- Return nothing if we failed to allocated an address
+        --
+        IF r_address IS NULL THEN
+                COMMIT;
+                LEAVE proc;
+        END IF;
+
+        -- 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 = NOW() + INTERVAL v_lease_duration SECOND
+        WHERE framedipaddress = r_address;
+
+        COMMIT;
+
+        -- Return the address that we allocated
+        SELECT r_address;
+
+END$$
+
+DELIMITER ;
index 0d7ff7f32d3727ccfff284474ab6f4c08cf6145e..2dfc6574ddc6c6c2854d1dda90273955574879c6 100644 (file)
@@ -116,6 +116,23 @@ allocate_update = "\
                username = '%{User-Name}', expiry_time = NOW() + INTERVAL ${lease_duration} SECOND \
        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 = "\
+#      CALL sp_allocate_previous_or_new_framedipaddress( \
+#              '%{control:${pool_name}}', \
+#              '%{User-Name}', \
+#              '%{Calling-Station-Id}', \
+#              '%{NAS-IP-Address}', \
+#              '${pool_key}', \
+#              ${lease_duration} \
+#      )"
+#allocate_update = ""
+#allocate_commit = ""
+
 #
 #  This series of queries frees an IP number when an accounting START record arrives.
 #