summaryrefslogtreecommitdiffstats
path: root/raddb/mods-config/sql/ippool-dhcp/oracle/procedure.sql
blob: 84b459627e9ed321f9f071e3951f8559adc40ece (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
--
-- 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; SELECT FOR UPDATE; UPDATE; COMMIT;  ->  SELECT sp() FROM dual
--
-- 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 = "\
--	SELECT fr_dhcp_allocate_previous_or_new_framedipaddress( \
--		'%{control:${pool_name}}', \
--		'%{DHCP-Gateway-IP-Address}', \
--		'${pool_key}', \
--		${lease_duration}, \
--		'%{%{${req_attribute_name}}:-0.0.0.0}' \
--	) FROM dual"
-- allocate_update = ""
-- allocate_commit = ""
--

CREATE OR REPLACE FUNCTION fr_dhcp_allocate_previous_or_new_framedipaddress (
	v_pool_name IN VARCHAR2,
	v_gateway IN VARCHAR2,
	v_pool_key IN VARCHAR2,
	v_lease_duration IN INTEGER,
	v_requested_address IN VARCHAR2
)
RETURN varchar2 IS
	PRAGMA AUTONOMOUS_TRANSACTION;
	r_address varchar2(15);
BEGIN

	-- Reissue an existing IP address lease when re-authenticating a session
	--
	BEGIN
		SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
			SELECT id FROM (
				SELECT *
				FROM dhcpippool
				JOIN dhcpstatus
				ON dhcpstatus.status_id = dhcpippool.status_id
				WHERE pool_name = v_pool_name
					AND expiry_time > current_timestamp
					AND pool_key = v_pool_key
					AND dhcpstatus.status IN ('dynamic', 'static')
			) WHERE ROWNUM <= 1
		) FOR UPDATE SKIP LOCKED;
	EXCEPTION
		WHEN NO_DATA_FOUND THEN
			r_address := NULL;
	END;

	-- Oracle >= 12c version of the above query
	--
	-- BEGIN
	--	SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
	--		SELECT id FROM dhcpippool
	--		JOIN dhcpstatus
	--		ON dhcpstatus.status_id = dhcpippool.status_id
	--		WHERE pool_name = v_pool_name
	--			AND expiry_time > current_timestamp
	--			AND pool_key = v_pool_key
	--			AND dhcpstatus.status IN ('dynamic', 'static')
	--		FETCH FIRST 1 ROWS ONLY
	--	) FOR UPDATE SKIP LOCKED;
	-- EXCEPTION
	--	WHEN NO_DATA_FOUND THEN
	--		r_address := NULL;
	-- END;



	-- 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.
	--
	-- BEGIN
	--	SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
	--		SELECT id FROM (
	--			SELECT *
	--			FROM dhcpippool
	--			JOIN dhcpstatus
	--			ON dhcpstatus.status_id = dhcpippool.status_id
	--			WHERE pool_name = v_pool_name
	--				AND pool_key = v_pool_key
	--				AND dhcpstatus.status IN ('dynamic', 'static')
	--			) WHERE ROWNUM <= 1
	--	) FOR UPDATE SKIP LOCKED;
	-- EXCEPTION
	--	WHEN NO_DATA_FOUND THEN
	--		r_address := NULL;
	-- END;

	-- Oracle >= 12c version of the above query
	--
	-- BEGIN
	--	SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
	--		SELECT id FROM dhcpippool
	--		JOIN dhcpstatus
	--		ON dhcpstatus.status_id = dhcpippool.status_id
	--		WHERE pool_name = v_pool_name
	--			AND pool_key = v_pool_key
	--			AND dhcpstatus.status IN ('dynamic', 'static')
	--	       FETCH FIRST 1 ROWS ONLY
	--       ) FOR UPDATE SKIP LOCKED;
	-- EXCEPTION
	--	   WHEN NO_DATA_FOUND THEN
	--	       r_address := NULL;
	-- END;



	-- Issue the requested IP address if it is available
	--
	IF r_address IS NULL AND v_requested_address <> '0.0.0.0' THEN
		BEGIN
		SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
			SELECT id FROM (
				SELECT *
				FROM dhcpippool
				JOIN dhcpstatus
				ON dhcpstatus.status_id = dhcpippool.status_id
				WHERE pool_name = v_pool_name
					AND framedipaddress = v_requested_address
					AND dhcpstatus.status = 'dynamic'
					AND expiry_time < CURRENT_TIMESTAMP
				) WHERE ROWNUM <= 1
		) FOR UPDATE SKIP LOCKED;
		EXCEPTION
		WHEN NO_DATA_FOUND THEN
			r_address := NULL;
		END;
	END IF;

	-- Oracle >= 12c version of the above query
	--
	-- IF r_address IS NULL AND v_requested_address <> '0.0.0.0' THEN
	--	BEGIN
	--	SELECT framedipaddress INTO r_address FROM dhcpippool WHERE id IN (
	--		SELECT id FROM dhcpippool
	--		JOIN dhcpstatus
	--		ON dhcpstatus.status_id = dhcpippool.status_id
	--		WHERE pool_name = v_pool_name
	--			AND framedipaddress = v_requested_address
	--			AND dhcpstatus.status = 'dynamic'
	--			AND expiry_time < CURRENT_TIMESTAMP
	--		FETCH FIRST 1 ROWS ONLY
	--	) FOR UPDATE SKIP LOCKED;
	--	EXCEPTION
	--	WHEN NO_DATA_FOUND THEN
	--		r_address := NULL;
	--	END;
	-- END IF;



	-- 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
		DECLARE
			l_cursor sys_refcursor;
		BEGIN
			OPEN l_cursor FOR
				SELECT framedipaddress
				FROM dhcpippool
				JOIN dhcpstatus
				ON dhcpstatus.status_id = dhcpippool.status_id
				WHERE pool_name = v_pool_name
				AND expiry_time < CURRENT_TIMESTAMP
				AND dhcpstatus.status = 'dynamic'
				ORDER BY expiry_time
				FOR UPDATE SKIP LOCKED;
			FETCH l_cursor INTO r_address;
			CLOSE l_cursor;
		EXCEPTION
			WHEN NO_DATA_FOUND THEN
				r_address := NULL;
		END;
	END IF;

	-- Return nothing if we failed to allocated an address
	--
	IF r_address IS NULL THEN
		COMMIT;
		RETURN r_address;
	END IF;

	-- Update the pool having allocated an IP address
	--
	UPDATE dhcpippool
	SET
		gateway = v_gateway,
		pool_key = v_pool_key,
		expiry_time = CURRENT_TIMESTAMP + v_lease_duration * INTERVAL '1' SECOND(1)
	WHERE framedipaddress = r_address;

	-- Return the address that we allocated
	COMMIT;
	RETURN r_address;

END;