blob: d5b61cf21b7b47e287f43a05d97f82bfbdff472f [file] [log] [blame]
Chetan Gaonker7f4bf742016-05-04 15:56:08 -07001# -*- text -*-
2#
3# main/postgresql/queries.conf -- PostgreSQL configuration for default schema (schema.sql)
4#
5# $Id: 0f2a29afff36136bb171a9a97ee90199b017e46c $
6
7# Safe characters list for sql queries. Everything else is replaced
8# with their mime-encoded equivalents.
9# The default list should be ok
10# safe_characters = "@abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789.-_: /"
11
12#######################################################################
13# Query config: Username
14#######################################################################
15# This is the username that will get substituted, escaped, and added
16# as attribute 'SQL-User-Name'. '%{SQL-User-Name}' should be used
17# below everywhere a username substitution is needed so you you can
18# be sure the username passed from the client is escaped properly.
19#
20# Uncomment the next line, if you want the sql_user_name to mean:
21#
22# Use Stripped-User-Name, if it's there.
23# Else use User-Name, if it's there,
24# Else use hard-coded string "none" as the user name.
25#
26#sql_user_name = "%{%{Stripped-User-Name}:-%{%{User-Name}:-none}}"
27
28sql_user_name = "%{User-Name}"
29
30#######################################################################
31# Default profile
32#######################################################################
33# This is the default profile. It is found in SQL by group membership.
34# That means that this profile must be a member of at least one group
35# which will contain the corresponding check and reply items.
36# This profile will be queried in the authorize section for every user.
37# The point is to assign all users a default profile without having to
38# manually add each one to a group that will contain the profile.
39# The SQL module will also honor the User-Profile attribute. This
40# attribute can be set anywhere in the authorize section (ie the users
41# file). It is found exactly as the default profile is found.
42# If it is set then it will *overwrite* the default profile setting.
43# The idea is to select profiles based on checks on the incoming
44# packets, not on user group membership. For example:
45# -- users file --
46# DEFAULT Service-Type == Outbound-User, User-Profile := "outbound"
47# DEFAULT Service-Type == Framed-User, User-Profile := "framed"
48#
49# By default the default_user_profile is not set
50#
51# default_user_profile = "DEFAULT"
52
53#######################################################################
54# Open Query
55#######################################################################
56# This query is run whenever a new connection is opened.
57# It is commented out by default.
58#
59# If you have issues with connections hanging for too long, uncomment
60# the next line, and set the timeout in milliseconds. As a general
61# rule, if the queries take longer than a second, something is wrong
62# with the database.
63#open_query = "set statement_timeout to 1000"
64
65#######################################################################
66# NAS Query
67#######################################################################
68# This query retrieves the radius clients
69#
70# 0. Row ID (currently unused)
71# 1. Name (or IP address)
72# 2. Shortname
73# 3. Type
74# 4. Secret
75# 5. Server
76#######################################################################
77
78client_query = "\
79 SELECT id, nasname, shortname, type, secret, server \
80 FROM ${client_table}"
81
82#######################################################################
83# Authorization Queries
84#######################################################################
85# These queries compare the check items for the user
86# in ${authcheck_table} and setup the reply items in
87# ${authreply_table}. You can use any query/tables
88# you want, but the return data for each row MUST
89# be in the following order:
90#
91# 0. Row ID (currently unused)
92# 1. UserName/GroupName
93# 2. Item Attr Name
94# 3. Item Attr Value
95# 4. Item Attr Operation
96#######################################################################
97
98#
99# Use these for case insensitive usernames. WARNING: Slower queries!
100#
101#authorize_check_query = "\
102# SELECT id, UserName, Attribute, Value, Op \
103# FROM ${authcheck_table} \
104# WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}') \
105# ORDER BY id"
106
107#authorize_reply_query = "\
108# SELECT id, UserName, Attribute, Value, Op \
109# FROM ${authreply_table} \
110# WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}') \
111# ORDER BY id"
112
113authorize_check_query = "\
114 SELECT id, UserName, Attribute, Value, Op \
115 FROM ${authcheck_table} \
116 WHERE Username = '%{SQL-User-Name}' \
117 ORDER BY id"
118
119authorize_reply_query = "\
120 SELECT id, UserName, Attribute, Value, Op \
121 FROM ${authreply_table} \
122 WHERE Username = '%{SQL-User-Name}' \
123 ORDER BY id"
124
125#
126# Use these for case insensitive usernames. WARNING: Slower queries!
127#
128#authorize_group_check_query = "\
129# SELECT \
130# ${groupcheck_table}.id, ${groupcheck_table}.GroupName, ${groupcheck_table}.Attribute, \
131# ${groupcheck_table}.Value, ${groupcheck_table}.Op \
132# FROM ${groupcheck_table}, ${usergroup_table} \
133# WHERE LOWER(${usergroup_table}.UserName) = LOWER('%{SQL-User-Name}') \
134# AND ${usergroup_table}.GroupName = ${groupcheck_table}.GroupName \
135# ORDER BY ${groupcheck_table}.id"
136
137#authorize_group_reply_query = "\
138# SELECT \
139# ${groupreply_table}.id, ${groupreply_table}.GroupName, \
140# ${groupreply_table}.Attribute, ${groupreply_table}.Value, ${groupreply_table}.Op \
141# FROM ${groupreply_table}, ${usergroup_table} \
142# WHERE LOWER(${usergroup_table}.UserName) = LOWER('%{SQL-User-Name}') \
143# AND ${usergroup_table}.GroupName = ${groupreply_table}.GroupName \
144# ORDER BY ${groupreply_table}.id"
145
146authorize_group_check_query = "\
147 SELECT id, GroupName, Attribute, Value, op \
148 FROM ${groupcheck_table} \
149 WHERE GroupName = '%{Sql-Group}' \
150 ORDER BY id"
151
152authorize_group_reply_query = "\
153 SELECT id, GroupName, Attribute, Value, op \
154 FROM ${groupreply_table} \
155 WHERE GroupName = '%{Sql-Group}' \
156 ORDER BY id"
157
158#######################################################################
159# Simultaneous Use Checking Queries
160#######################################################################
161# simul_count_query - query for the number of current connections
162# - If this is not defined, no simultaneous use checking
163# - will be performed by this module instance
164# simul_verify_query - query to return details of current connections for verification
165# - Leave blank or commented out to disable verification step
166# - Note that the returned field order should not be changed.
167#######################################################################
168
169#
170# Uncomment simul_count_query to enable simultaneous use checking
171#
172#simul_count_query = "\
173# SELECT COUNT(*) \
174# FROM ${acct_table1} \
175# WHERE UserName='%{SQL-User-Name}' \
176# AND AcctStopTime IS NULL"
177
178#simul_verify_query = "\
179# SELECT RadAcctId, AcctSessionId, UserName, NASIPAddress, NASPortId, FramedIPAddress, CallingStationId, \
180# FramedProtocol \
181# FROM ${acct_table1} \
182# WHERE UserName='%{SQL-User-Name}' \
183# AND AcctStopTime IS NULL"
184
185#######################################################################
186# Group Membership Queries
187#######################################################################
188# group_membership_query - Check user group membership
189#######################################################################
190
191# Use these for case insensitive usernames. WARNING: Slower queries!
192#group_membership_query = "\
193# SELECT GroupName \
194# FROM ${usergroup_table} \
195# WHERE LOWER(UserName) = LOWER('%{SQL-User-Name}') \
196# ORDER BY priority"
197
198group_membership_query = "\
199 SELECT GroupName \
200 FROM ${usergroup_table} \
201 WHERE UserName='%{SQL-User-Name}' \
202 ORDER BY priority"
203
204#######################################################################
205# Accounting and Post-Auth Queries
206#######################################################################
207# These queries insert/update accounting and authentication records.
208# The query to use is determined by the value of 'reference'.
209# This value is used as a configuration path and should resolve to one
210# or more 'query's. If reference points to multiple queries, and a query
211# fails, the next query is executed.
212#
213# Behaviour is identical to the old 1.x/2.x module, except we can now
214# fail between N queries, and query selection can be based on any
215# combination of attributes, or custom 'Acct-Status-Type' values.
216#######################################################################
217accounting {
218 reference = "%{tolower:type.%{%{Acct-Status-Type}:-none}.query}"
219
220 # Write SQL queries to a logfile. This is potentially useful for bulk inserts
221 # when used with the rlm_sql_null driver.
222# logfile = ${logdir}/accounting.sql
223
224 column_list = "\
225 AcctSessionId, AcctUniqueId, UserName, \
226 Realm, NASIPAddress, NASPortId, \
227 NASPortType, AcctStartTime, AcctUpdateTime, \
228 AcctStopTime, AcctSessionTime, AcctAuthentic, \
229 ConnectInfo_start, ConnectInfo_Stop, AcctInputOctets, \
230 AcctOutputOctets, CalledStationId, CallingStationId, \
231 AcctTerminateCause, ServiceType, FramedProtocol, \
232 FramedIpAddress"
233
234 type {
235 accounting-on {
236 query = "\
237 UPDATE ${....acct_table1} \
238 SET \
239 AcctStopTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
240 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
241 AcctSessionTime = (%{integer:Event-Timestamp} - EXTRACT(EPOCH FROM(AcctStartTime))), \
242 AcctTerminateCause = '%{%{Acct-Terminate-Cause}:-NAS-Reboot}', \
243 WHERE AcctStopTime IS NULL \
244 AND NASIPAddress= '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}' \
245 AND AcctStartTime <= '%S'::timestamp"
246 }
247
248 accounting-off {
249 query = "${..accounting-on.query}"
250 }
251
252 start {
253 query = "\
254 INSERT INTO ${....acct_table1} \
255 (${...column_list}) \
256 VALUES(\
257 '%{Acct-Session-Id}', \
258 '%{Acct-Unique-Session-Id}', \
259 '%{SQL-User-Name}', \
260 NULLIF('%{Realm}', ''), \
261 '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}', \
262 %{%{NAS-Port}:-NULL}, \
263 '%{NAS-Port-Type}', \
264 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
265 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
266 NULL, \
267 0, \
268 '%{Acct-Authentic}', \
269 '%{Connect-Info}', \
270 NULL, \
271 0, \
272 0, \
273 '%{Called-Station-Id}', \
274 '%{Calling-Station-Id}', \
275 NULL, \
276 '%{Service-Type}', \
277 '%{Framed-Protocol}', \
278 NULLIF('%{Framed-IP-Address}', '')::inet)"
279
280 query = "\
281 UPDATE ${....acct_table1} \
282 SET \
283 AcctStartTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
284 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
285 ConnectInfo_start = '%{Connect-Info}' \
286 WHERE AcctSessionId = '%{Acct-Session-Id}' \
287 AND UserName = '%{SQL-User-Name}' \
288 AND NASIPAddress = '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}' \
289 AND AcctStopTime IS NULL"
290
291 # and again where we don't have "AND AcctStopTime IS NULL"
292 query = "\
293 UPDATE ${....acct_table1} \
294 SET \
295 AcctStartTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
296 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
297 ConnectInfo_start = '%{Connect-Info}' \
298 WHERE AcctSessionId = '%{Acct-Session-Id}' \
299 AND UserName = '%{SQL-User-Name}' \
300 AND NASIPAddress = '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}'"
301 }
302
303 interim-update {
304 query = "\
305 UPDATE ${....acct_table1} \
306 SET \
307 FramedIPAddress = NULLIF('%{Framed-IP-Address}', '')::inet, \
308 AcctSessionTime = %{%{Acct-Session-Time}:-NULL}, \
309 AcctInterval = (%{integer:Event-Timestamp} - EXTRACT(EPOCH FROM (COALESCE(AcctUpdateTime, AcctStartTime)))), \
310 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
311 AcctInputOctets = (('%{%{Acct-Input-Gigawords}:-0}'::bigint << 32) + \
312 '%{%{Acct-Input-Octets}:-0}'::bigint), \
313 AcctOutputOctets = (('%{%{Acct-Output-Gigawords}:-0}'::bigint << 32) + \
314 '%{%{Acct-Output-Octets}:-0}'::bigint) \
315 WHERE AcctSessionId = '%{Acct-Session-Id}' \
316 AND UserName = '%{SQL-User-Name}' \
317 AND NASIPAddress= '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}' \
318 AND AcctStopTime IS NULL"
319
320 query = "\
321 INSERT INTO ${....acct_table1} \
322 (${...column_list}) \
323 VALUES(\
324 '%{Acct-Session-Id}', \
325 '%{Acct-Unique-Session-Id}', \
326 '%{SQL-User-Name}', \
327 NULLIF('%{Realm}', ''), \
328 '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}', \
329 %{%{NAS-Port}:-NULL}, \
330 '%{NAS-Port-Type}', \
331 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
332 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
333 NULL, \
334 %{%{Acct-Session-Time}:-NULL}, \
335 '%{Acct-Authentic}', \
336 '%{Connect-Info}', \
337 NULL, \
338 (('%{%{Acct-Input-Gigawords}:-0}'::bigint << 32) + \
339 '%{%{Acct-Input-Octets}:-0}'::bigint), \
340 (('%{%{Acct-Output-Gigawords}:-0}'::bigint << 32) + \
341 '%{%{Acct-Output-Octets}:-0}'::bigint), \
342 '%{Called-Station-Id}', \
343 '%{Calling-Station-Id}', \
344 NULL, \
345 '%{Service-Type}', \
346 '%{Framed-Protocol}', \
347 NULLIF('%{Framed-IP-Address}', '')::inet)"
348 }
349
350 stop {
351 query = "\
352 UPDATE ${....acct_table2} \
353 SET \
354 AcctStopTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
355 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
356 AcctSessionTime = COALESCE(%{%{Acct-Session-Time}:-NULL}, \
357 (%{integer:Event-Timestamp} - EXTRACT(EPOCH FROM(AcctStartTime)))), \
358 AcctInputOctets = (('%{%{Acct-Input-Gigawords}:-0}'::bigint << 32) + \
359 '%{%{Acct-Input-Octets}:-0}'::bigint), \
360 AcctOutputOctets = (('%{%{Acct-Output-Gigawords}:-0}'::bigint << 32) + \
361 '%{%{Acct-Output-Octets}:-0}'::bigint), \
362 AcctTerminateCause = '%{Acct-Terminate-Cause}', \
363 FramedIPAddress = NULLIF('%{Framed-IP-Address}', '')::inet, \
364 ConnectInfo_stop = '%{Connect-Info}' \
365 WHERE AcctSessionId = '%{Acct-Session-Id}' \
366 AND UserName = '%{SQL-User-Name}' \
367 AND NASIPAddress = '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}' \
368 AND AcctStopTime IS NULL"
369
370 query = "\
371 INSERT INTO ${....acct_table1} \
372 (${...column_list}) \
373 VALUES(\
374 '%{Acct-Session-Id}', \
375 '%{Acct-Unique-Session-Id}', \
376 '%{SQL-User-Name}', \
377 NULLIF('%{Realm}', ''), \
378 '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}', \
379 %{%{NAS-Port}:-NULL}, \
380 '%{NAS-Port-Type}', \
381 TO_TIMESTAMP(%{integer:Event-Timestamp} - %{%{Acct-Session-Time}:-0}), \
382 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
383 TO_TIMESTAMP(%{integer:Event-Timestamp}), \
384 NULLIF('%{Acct-Session-Time}', '')::bigint, \
385 '%{Acct-Authentic}', \
386 '%{Connect-Info}', \
387 NULL, \
388 (('%{%{Acct-Input-Gigawords}:-0}'::bigint << 32) + \
389 '%{%{Acct-Input-Octets}:-0}'::bigint), \
390 (('%{%{Acct-Output-Gigawords}:-0}'::bigint << 32) + \
391 '%{%{Acct-Output-Octets}:-0}'::bigint), \
392 '%{Called-Station-Id}', \
393 '%{Calling-Station-Id}', \
394 '%{Acct-Terminate-Cause}', \
395 '%{Service-Type}', \
396 '%{Framed-Protocol}', \
397 NULLIF('%{Framed-IP-Address}', '')::inet)"
398
399 # and again where we don't have "AND AcctStopTime IS NULL"
400 query = "\
401 UPDATE ${....acct_table2} \
402 SET \
403 AcctStopTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
404 AcctUpdateTime = TO_TIMESTAMP(%{integer:Event-Timestamp}), \
405 AcctSessionTime = COALESCE(%{%{Acct-Session-Time}:-NULL}, \
406 (%{integer:Event-Timestamp} - EXTRACT(EPOCH FROM(AcctStartTime)))), \
407 AcctInputOctets = (('%{%{Acct-Input-Gigawords}:-0}'::bigint << 32) + \
408 '%{%{Acct-Input-Octets}:-0}'::bigint), \
409 AcctOutputOctets = (('%{%{Acct-Output-Gigawords}:-0}'::bigint << 32) + \
410 '%{%{Acct-Output-Octets}:-0}'::bigint), \
411 AcctTerminateCause = '%{Acct-Terminate-Cause}', \
412 FramedIPAddress = NULLIF('%{Framed-IP-Address}', '')::inet, \
413 ConnectInfo_stop = '%{Connect-Info}' \
414 WHERE AcctSessionId = '%{Acct-Session-Id}' \
415 AND UserName = '%{SQL-User-Name}' \
416 AND NASIPAddress = '%{%{NAS-IPv6-Address}:-%{NAS-IP-Address}}'"
417 }
418
419 #
420 # No Acct-Status-Type == ignore the packet
421 #
422 none {
423 query = "SELECT true"
424 }
425 }
426}
427
428
429#######################################################################
430# Authentication Logging Queries
431#######################################################################
432# postauth_query - Insert some info after authentication
433#######################################################################
434
435post-auth {
436 # Write SQL queries to a logfile. This is potentially useful for bulk inserts
437 # when used with the rlm_sql_null driver.
438# logfile = ${logdir}/post-auth.sql
439
440 query = "\
441 INSERT INTO ${..postauth_table} \
442 (username, pass, reply, authdate) \
443 VALUES(\
444 '%{User-Name}', \
445 '%{%{User-Password}:-Chap-Password}', \
446 '%{reply:Packet-Type}', \
447 NOW())"
448}