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
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
|
# -*- text -*-
#
# ippool-dhcp/postgresql/queries.conf -- PostgreSQL queries for rlm_sqlippool
#
# $Id$
# *****************
# * DHCP DISCOVER *
# *****************
#
# Use a stored procedure to find AND allocate the address. Read and customise
# `procedure.sql` in this directory to determine the optimal configuration.
#
# This requires PostgreSQL >= 9.5 as SKIP LOCKED is used.
#
# The "NO LOAD BALANCE" comment is included here to indicate to a PgPool
# system that this needs to be a write transaction. PgPool itself cannot
# detect this from the statement alone. If you are using PgPool and do not
# have this comment, the query may go to a read only server, and will fail.
# This has no negative effect if you are not using PgPool.
#
allocate_begin = ""
allocate_find = "\
/*NO LOAD BALANCE*/ \
SELECT fr_dhcp_allocate_previous_or_new_framedipaddress( \
'%{control:${pool_name}}', \
'%{DHCP-Gateway-IP-Address}', \
'${pool_key}', \
'${offer_duration}', \
'%{%{${req_attribute_name}}:-0.0.0.0}' \
)"
allocate_update = ""
allocate_commit = ""
#
# If stored procedures are not able to be used, the following queries can
# be used.
# Comment out all the above queries and choose the appropriate "allocate_find"
# to match the desired outcome and also the version of "allocate_update" below.
#
#
# This sequence of queries allocates an IP address from the Pool
#
#allocate_begin = "BEGIN"
# Attempt to find the most recent existing IP address for the client
#
#allocate_existing = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND pool_key = '${pool_key}' \
# AND status IN ('dynamic', 'static') \
# ORDER BY expiry_time DESC \
# LIMIT 1 \
# FOR UPDATE"
# The same query with SKIP LOCKED - requires PostgreSQL >= 9.5
# allocate_existing = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND pool_key = '${pool_key}' \
# AND status IN ('dynamic', 'static') \
# ORDER BY expiry_time DESC \
# LIMIT 1 \
# FOR UPDATE SKIP LOCKED"
#
# Determine whether the requested IP address is available
#
#allocate_requested = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND framedipaddress = '%{%{${req_attribute_name}}:-0.0.0.0}' \
# AND status = 'dynamic' \
# AND expiry_time < 'now'::timestamp(0) \
# FOR UPDATE"
# The same query with SKIP LOCKED - requires PostgreSQL >= 9.5
#allocate_requested = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND framedipaddress = '%{%{${req_attribute_name}}:-0.0.0.0}' \
# AND status = 'dynamic' \
# AND expiry_time < 'now'::timestamp(0) \
# FOR UPDATE SKIP LOCKED"
#
# 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} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND expiry_time < 'now'::timestamp(0) \
# AND status = 'dynamic' \
# ORDER BY expiry_time \
# LIMIT 1 \
# FOR UPDATE"
# The same query with SKIP LOCKED - requires PostgreSQL >= 9.5
#allocate_find = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND expiry_time < 'now'::timestamp(0) \
# AND status = 'dynamic' \
# ORDER BY expiry_time \
# LIMIT 1 \
# FOR UPDATE SKIP LOCKED"
#
# 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.
# Use of either of these next two queries should have the allocate_begin line commented out
# and allocate_update below un-commented.
#
#allocate_find = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' AND expiry_time < 'now'::timestamp(0) \
# AND status = 'dynamic' \
# ORDER BY RANDOM() \
# LIMIT 1 \
# FOR UPDATE"
#
# The above query again, but with SKIP LOCKED. This requires PostgreSQL >= 9.5.
#
#allocate_find = "\
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' AND expiry_time < 'now'::timestamp(0) \
# AND status = 'dynamic' \
# ORDER BY RANDOM() \
# LIMIT 1 \
# FOR UPDATE SKIP LOCKED"
#
# This query marks the IP address handed out by "allocate-find" as used
# for the period of "lease_duration" after which time it may be reused.
#
#allocate_update = "\
# UPDATE ${ippool_table} \
# SET \
# gateway = '%{DHCP-Gateway-IP-Address}', \
# pool_key = '${pool_key}', \
# expiry_time = 'now'::timestamp(0) + '${offer_duration} second'::interval \
# WHERE framedipaddress = '%I'"
#
# Alternatively, merge the matching of existing IP and free IP into a single query
# This version does the update as well - so allocate_begin, allocate_update and
# allocate_commit should be blank
#
#allocate_begin = ""
#allocate_find = "\
# WITH found AS ( \
# WITH existing AS ( \
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND pool_key = '${pool_key}' \
# ORDER BY expiry_time DESC \
# LIMIT 1 \
# FOR UPDATE SKIP LOCKED \
# ), requested AS ( \
# SELECT framedipaddress FROM ${ippool_table} \
# 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 < 'now'::timestamp(0) ) \
# FOR UPDATE SKIP LOCKED \
# ), new AS ( \
# SELECT framedipaddress FROM ${ippool_table} \
# WHERE pool_name = '%{control:${pool_name}}' \
# AND expiry_time < 'now'::timestamp(0) \
# AND status = 'dynamic' \
# ORDER BY expiry_time \
# LIMIT 1 \
# FOR UPDATE SKIP LOCKED \
# ) \
# SELECT framedipaddress, 1 AS o FROM existing \
# UNION ALL \
# SELECT framedipaddress, 2 AS o FROM requested \
# UNION ALL \
# SELECT framedipaddress, 3 AS o FROM new \
# ORDER BY o LIMIT 1 \
# ) \
# UPDATE ${ippool_table} \
# SET pool_key = '${pool_key}', \
# expiry_time = 'now'::timestamp(0) + '${offer_duration} second'::interval, \
# gateway = '%{DHCP-Gateway-IP-Address}' \
# FROM found \
# WHERE found.framedipaddress = ${ippool_table}.framedipaddress \
# RETURNING found.framedipaddress"
#allocate_update = ""
#allocate_commit = ""
#
# If an IP could not be allocated, check to see whether 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"
# ****************
# * DHCP REQUEST *
# ****************
#
# This query revokes any active offers for addresses that a client is not
# requesting when a DHCP REQUEST packet arrives, i.e, each server (sharing the
# same database) may have simultaneously offered a unique address.
#
start_update = "\
UPDATE ${ippool_table} \
SET \
gateway = '', \
pool_key = '', \
expiry_time = 'now'::timestamp(0) - '1 second'::interval \
WHERE pool_name = '%{control:${pool_name}}' \
AND pool_key = '${pool_key}' \
AND framedipaddress <> '%{DHCP-Requested-IP-Address}' \
AND expiry_time > 'now'::timestamp(0) \
AND 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 = 'now'::timestamp(0) + '${lease_duration} second'::interval, \
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 = 'now'::timestamp(0) - '1 second'::interval \
WHERE pool_name = '%{control:${pool_name}}' \
AND pool_key = '${pool_key}' \
AND framedipaddress = '%{DHCP-Client-IP-Address}' \
AND 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 = 'declined' \
WHERE pool_name = '%{control:${pool_name}}' \
AND pool_key = '${pool_key}' \
AND framedipaddress = '%{DHCP-Requested-IP-Address}'"
|