summaryrefslogtreecommitdiffstats
path: root/raddb/mods-config/sql/ippool-dhcp/sqlite/queries.conf
blob: d99e09bfc8559eaf5584c32fb6a94c99e689fee3 (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
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
# -*- text -*-
#
#  ippool-dhcp/sqlite/queries.conf -- SQLite queries for rlm_sqlippool
#
#  $Id$

#  *****************
#  * DHCP DISCOVER *
#  *****************

#
#  SQLite does not implement SELECT FOR UPDATE which is normally used to place
#  an exclusive lock over rows to prevent the same address from being
#  concurrently selected for allocation to multiple users.
#
#  The most granular read-blocking lock that SQLite has is an exclusive lock
#  over the database, so that's what we use. All locking in SQLite is performed
#  over the entire database and we perform a row update for any IP that we
#  allocate, requiring an exclusive lock. Taking the exclusive lock from the
#  start of the transaction (even if it were not required to guard the SELECT)
#  is actually quicker than if we deferred it causing SQLite to "upgrade" the
#  automatic shared lock for the transaction to an exclusive lock for the
#  subsequent UPDATE.
#
allocate_begin = "BEGIN EXCLUSIVE"
allocate_commit = "COMMIT"

#
#  Attempt to find the most recent existing IP address for the client
#
allocate_existing = "\
	SELECT framedipaddress \
	FROM ${ippool_table} \
	JOIN dhcpstatus \
	ON ${ippool_table}.status_id = dhcpstatus.status_id \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND pool_key = '${pool_key}' \
	AND status IN ('dynamic', 'static') \
	ORDER BY expiry_time DESC \
	LIMIT 1"

#
#  Determine whether the requested IP address is available
#
allocate_requested = "\
	SELECT framedipaddress \
	FROM ${ippool_table} \
	JOIN dhcpstatus \
	ON ${ippool_table}.status_id = dhcpstatus.status_id \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND framedipaddress = '%{%{${req_attribute_name}}:-0.0.0.0}' \
	AND status = 'dynamic' \
	AND expiry_time < datetime('now')"

#
#  If the existing address can't be found this query will be run to
#  find a free address
#
allocate_find = "\
	SELECT framedipaddress \
	FROM ${ippool_table} \
	JOIN dhcpstatus \
	ON ${ippool_table}.status_id = dhcpstatus.status_id \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND expiry_time < datetime('now') \
	AND status = 'dynamic' \
	ORDER BY expiry_time LIMIT 1"

#
#  This series of queries allocates an IP address
#
#  Either pull the most recent allocated IP for this client or the
#  oldest expired one.  The first sub query returns the most recent
#  lease for the client (if there is one), the second returns the
#  oldest expired one.
#  Sorting the result by expiry_time DESC will return the client specific
#  IP if it exists, otherwise an expired one.
#
#allocate_find = "\
#	SELECT framedipaddress, 1 AS o \
#	FROM ( \
#		SELECT framedipaddress \
#		FROM ${ippool_table} \
#		JOIN dhcpstatus \
#		ON ${ippool_table}.status_id = dhcpstatus.status_id \
#		WHERE pool_name = '%{control:${pool_name}}' \
#		AND pool_key = '${pool_key}' \
#		AND status IN ('dynamic', 'static') \
#		ORDER BY expiry_time DESC \
#		LIMIT 1 \
#	) UNION \
#	SELECT framedipaddress, 2 AS o \
#	FROM ( \
#		SELECT framedipaddress \
#		FROM ${ippool_table} \
#		JOIN dhcpstatus \
#		ON ${ippool_table}.status_id = dhcpstatus.status_id \
#		WHERE pool_name = '%{control:${pool_name}}' \
#		AND framedipaddress = '%{%{${req_attribute_name}}:-0.0.0.0}' \
#		AND status = 'dynamic' \
#		AND ( pool_key = '${pool_key}' OR expiry_time < datetime('now') ) \
#	) UNION \
#	SELECT framedipaddress, 3 AS o \
#	FROM ( \
#		SELECT framedipaddress \
#		FROM ${ippool_table} \
#		JOIN dhcpstatus \
#		ON ${ippool_table}.status_id = dhcpstatus.status_id \
#		WHERE pool_name = '%{control:${pool_name}}' \
#		AND expiry_time < datetime('now') \
#		AND status = 'dynamic' \
#		ORDER BY expiry_time LIMIT 1 \
#	) \
#	ORDER BY o \
#	LIMIT 1"

#
#   If you prefer to allocate a random IP address every time, i
#   use this query instead
#   Note: This is very slow if you have a lot of free IPs.
#

#allocate_find = "\
#	SELECT framedipaddress \
#	FROM ${ippool_table} \
#	JOIN dhcpstatus \
#	ON ${ippool_table}.status_id = dhcpstatus.status_id \
# 	WHERE pool_name = '%{control:${pool_name}}' \
#	AND expiry_time < datetime('now') \
#	AND status = 'dynamic' \
#	ORDER BY RAND() \


#
#  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 id \
	FROM ${ippool_table} \
	WHERE pool_name='%{control:${pool_name}}' \
	LIMIT 1"

#
#  This is the final IP Allocation query, which saves the allocated ip details
#
allocate_update = "\
	UPDATE ${ippool_table} \
	SET \
		gateway = '%{DHCP-Gateway-IP-Address}', \
		pool_key = '${pool_key}', \
		expiry_time = datetime(strftime('%%s', 'now') + ${offer_duration}, 'unixepoch') \
	WHERE framedipaddress = '%I'"


# ****************
# * DHCP REQUEST *
# ****************

#
#  This query revokes any active offers for addresses that a client is not
#  requesting when a DHCP REQUEST packet arrives
#
start_update = "\
	UPDATE ${ippool_table} \
	SET \
		gateway = '', \
		pool_key = '', \
		expiry_time = datetime('now') \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND pool_key = '${pool_key}' \
	AND framedipaddress <> '%{DHCP-Requested-IP-Address}' \
	AND expiry_time > datetime('now') \
	AND ${ippool_table}.status_id IN \
	(SELECT status_id FROM dhcpstatus WHERE status = 'dynamic')"

#
#  This query extends an existing lease (or offer) when a DHCP REQUEST packet
#  arrives.  This query must update a row when a lease is succesfully requested
#  - queries that update no rows will result in a "notfound" response to
#  the module which by default will give a DHCP-NAK reply.  In this example
#  incrementing "counter" is used to achieve this.
#
alive_update = "\
	UPDATE ${ippool_table} \
	SET \
		expiry_time = datetime(strftime('%%s', 'now') + ${lease_duration}, 'unixepoch'), \
		counter = counter + 1 \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND pool_key = '${pool_key}' \
	AND framedipaddress = '%{%{DHCP-Requested-IP-Address}:-%{DHCP-Client-IP-Address}}'"


# ****************
# * DHCP RELEASE *
# ****************

#
#  This query frees an IP address when a DHCP RELEASE packet arrives
#
stop_clear = "\
	UPDATE ${ippool_table} \
	SET \
		gateway = '', \
		pool_key = '', \
		expiry_time = datetime('now') \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND pool_key = '${pool_key}' \
	AND framedipaddress = '%{DHCP-Client-IP-Address}' \
	AND ${ippool_table}.status_id IN \
	(SELECT status_id FROM dhcpstatus WHERE status = 'dynamic')"


#
#  This query is not applicable to DHCP
#
on_clear = ""


# ****************
# * DHCP DECLINE *
# ****************

#
#  This query marks an IP address as declined when a DHCP Decline
#  packet arrives
#
off_clear = "\
	UPDATE ${ippool_table} \
	SET status_id = (SELECT status_id FROM dhcpstatus WHERE status = 'declined') \
	WHERE pool_name = '%{control:${pool_name}}' \
	AND pool_key = '${pool_key}' \
	AND framedipaddress = '%{DHCP-Requested-IP-Address}'"