summaryrefslogtreecommitdiffstats
path: root/scripts/sql/align_sql_pools.pl
blob: 04d2d4bf408524f686c3abcc2f6da2dc644d4dc1 (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
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
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
#!/usr/bin/perl -Tw

######################################################################
#
#  Copyright (C) 2020 Network RADIUS
#
#  $Id$
#
######################################################################
#
#  Helper script for generating the SQL commands to align the SQL IP pools in a
#  database with a given specification.
#
#  The radippool table is updated is a way that preserves existing leases,
#  provided that the corresponding IP addresses still exist in their pool.
#
#  This script typically receives the output of the generate_pool_addresses.pl
#  script, as follows:
#
#    generate_pool_addresses.pl <options> | align_sqlippools.pl <sql_dialect>
#
#  For example:
#
#    generate_pool_addresses.pl main_pool 10.0.1.0 10.0.1.255 | \
#            align_sqlippools.pl mariadb
#
#    generate_pool_addresses.pl yaml pool_defs.yml existing_ips.txt | \
#            align_sqlippools.pl postgresql
#
#  For the latter example the existing_ips.txt file might be created as
#  follows:
#
#    psql radius -qtAc 'SELECT framedipaddress FROM radippool' > existing_ips.txt
#
#  Note: The generate_pool_addresses.pl script describes the input format
#  expected by this script (as well as the format of the pool_defs.yml and
#  existing_ips.txt files.)
#
#  Output:
#
#  The output of this script is the SQL command sequence for aligning the pools
#  with the definition provided, which you should review before running them
#  against your database.
#

use strict;
use Template;

my %template=load_templates();

if ($#ARGV != 0) {
	print STDERR <<'EOF';
Usage: generate_pool_addresses.pl ... | align_sqlippools.pl <dialect>

EOF
	exit 1;
}

my $dialect=$ARGV[0];

unless (defined $template{$dialect}) {
	print STDERR "Unknown dialect. Pick one of: ";
	print STDERR "$_ " foreach sort keys %template;
	print STDERR "\n";
	exit 1;
}

my @ips=();

my $line = 0;
while (<STDIN>) {
	$line++;

	chomp;

	next if $_ =~ /^#/ || $_ =~ /^\s*$/;

	# The SQL works out what addresses to remove by itself
	next if $_ =~ /^-/;

	(my $action, my $pool_name, my $ip) = $_ =~ /^(.)\s+(.+)\s+([^\s]+)$/;

	unless (defined $ip) {
		warn "Unrecognised line $line: $_";
		next;
	}

	push @ips, { poolname => $pool_name, ip => $ip };

}

my $tt=Template->new();
$tt->process(\$template{$dialect}, {ips => \@ips, batchsize => 100}) || die $tt->error();

exit 0;


#
#  SQL dialect templates
#

sub load_templates {

	my %template;

#
#  MariaDB
#
	$template{'mariadb'} = <<'END_mariadb';
-- Temporary table holds the provided IP pools
DROP TEMPORARY TABLE IF EXISTS radippool_temp;
CREATE TEMPORARY TABLE radippool_temp (
  id                    int(11) unsigned NOT NULL auto_increment,
  pool_name             varchar(30) NOT NULL,
  framedipaddress       varchar(15) NOT NULL,
  PRIMARY KEY (id),
  KEY pool_name_framedipaddress (pool_name,framedipaddress)
);

-- Populate the temporary table
[%- FOREACH m IN ips %]
[%- "\n\nINSERT INTO radippool_temp (pool_name,framedipaddress) VALUES" IF loop.index % batchsize == 0 %]
[%-   IF (loop.index+1) % batchsize == 0 OR loop.last %]
('[% m.poolname %]','[% m.ip %]');
[%-   ELSE %]
('[% m.poolname %]','[% m.ip %]'),
[%-   END %]
[%- END %]

START TRANSACTION;

-- Delete old pools that have been removed
DELETE r FROM radippool r
  LEFT JOIN radippool_temp t USING (pool_name,framedipaddress)
      WHERE t.id IS NULL;

-- Add new pools that have been created
INSERT INTO radippool (pool_name,framedipaddress)
  SELECT pool_name,framedipaddress FROM radippool_temp t WHERE NOT EXISTS (
    SELECT * FROM radippool r
    WHERE r.pool_name=t.pool_name AND r.framedipaddress=t.framedipaddress
  );

COMMIT;
END_mariadb


#
#  PostgreSQL
#
	$template{'postgresql'} = <<'END_postgresql';
-- Temporary table holds the provided IP pools
DROP TABLE IF EXISTS radippool_temp;
CREATE TEMPORARY TABLE radippool_temp (
  pool_name               varchar(64) NOT NULL,
  FramedIPAddress         INET NOT NULL
);
CREATE INDEX radippool_temp_idx ON radippool_temp USING btree (pool_name,FramedIPAddress);

-- Populate the temporary table
[%- FOREACH m IN ips %]
[%- "\n\nINSERT INTO radippool_temp (pool_name,framedipaddress) VALUES" IF loop.index % batchsize == 0 %]
[%-   IF (loop.index+1) % batchsize == 0 OR loop.last %]
('[% m.poolname %]','[% m.ip %]');
[%-   ELSE %]
('[% m.poolname %]','[% m.ip %]'),
[%-   END %]
[%- END %]

START TRANSACTION;

-- Delete old pools that have been removed
DELETE FROM radippool r WHERE NOT EXISTS (
  SELECT FROM radippool_temp t
  WHERE t.pool_name = r.pool_name AND t.framedipaddress = r.framedipaddress
);

-- Add new pools that have been created
INSERT INTO radippool (pool_name,framedipaddress)
  SELECT pool_name,framedipaddress FROM radippool_temp t WHERE NOT EXISTS (
    SELECT * FROM radippool r
    WHERE r.pool_name=t.pool_name AND r.framedipaddress=t.framedipaddress
  );

COMMIT;
END_postgresql

#
#  Oracle
#
	$template{'oracle'} = <<'END_oracle';
-- Temporary table holds the provided IP pools
CREATE GLOBAL TEMPORARY TABLE radippool_temp (
  pool_name               VARCHAR(30) NOT NULL,
  FramedIPAddress         VARCHAR(15) NOT NULL
) ON COMMIT DELETE ROWS;
CREATE INDEX radippool_temp_idx ON radippool_temp (pool_name,FramedIPAddress);

-- Populate the temporary table
[%- FOREACH m IN ips %]
[%- "\nINSERT INTO radippool_temp (pool_name,framedipaddress) VALUES " %]('[% m.poolname %]','[% m.ip %]');
[%- END %]

-- Delete old pools that have been removed
DELETE FROM radippool WHERE (pool_name, framedipaddress)
  NOT IN (SELECT pool_name, framedipaddress FROM radippool_temp);

-- Add new pools that have been created
INSERT INTO radippool (pool_name,framedipaddress)
  SELECT pool_name,framedipaddress FROM radippool_temp t WHERE NOT EXISTS (
    SELECT * FROM radippool r
    WHERE r.pool_name=t.pool_name AND r.framedipaddress=t.framedipaddress
  );

COMMIT;
END_oracle

#
#  SQLite
#

	$template{'sqlite'} = <<'END_sqlite';
-- Temporary table holds the provided IP pools
DROP TABLE IF EXISTS radippool_temp;
CREATE TABLE radippool_temp (
  pool_name             varchar(30) NOT NULL,
  framedipaddress       varchar(15) NOT NULL
);

CREATE INDEX radippool_temp_idx ON radippool_temp (pool_name,FramedIPAddress);

-- Populate the temporary table
[%- FOREACH m IN ips %]
[%- "\n\nINSERT INTO radippool_temp (pool_name,framedipaddress) VALUES" IF loop.index % batchsize == 0 %]
[%-   IF (loop.index+1) % batchsize == 0 OR loop.last %]
('[% m.poolname %]','[% m.ip %]');
[%-   ELSE %]
('[% m.poolname %]','[% m.ip %]'),
[%-   END %]
[%- END %]

BEGIN TRANSACTION;

-- Delete old pools that have been removed
DELETE FROM radippool WHERE rowid IN (
  SELECT r.rowid FROM radippool r
  LEFT JOIN radippool_temp t USING (pool_name,framedipaddress)
      WHERE t.rowid IS NULL);

-- Add new pools that have been created
INSERT INTO radippool (pool_name,framedipaddress)
  SELECT pool_name,framedipaddress FROM radippool_temp t WHERE NOT EXISTS (
    SELECT * FROM radippool r
    WHERE r.pool_name=t.pool_name AND r.framedipaddress=t.framedipaddress
  );

COMMIT;

DROP TABLE radippool_temp;
END_sqlite

#
#  MS SQL
#
	$template{'mssql'} = <<'END_mssql';
-- Temporary table holds the provided IP pools
DROP TABLE IF EXISTS #radippool_temp;
GO

CREATE TABLE #radippool_temp (
  id                    int identity(1, 1) NOT NULL,
  pool_name             varchar(30) NOT NULL,
  framedipaddress       varchar(15) NOT NULL,
  PRIMARY KEY (id),
);
GO

CREATE INDEX pool_name_framedipaddress ON #radippool_temp(pool_name, framedipaddress);
GO

-- Populate the temporary table
[%- FOREACH m IN ips %]
[%- "\n\nINSERT INTO #radippool_temp (pool_name,framedipaddress) VALUES" IF loop.index % batchsize == 0 %]
[%-   IF (loop.index+1) % batchsize == 0 OR loop.last %]
('[% m.poolname %]','[% m.ip %]');
GO
[%-   ELSE %]
('[% m.poolname %]','[% m.ip %]'),
[%-   END %]
[%- END %]

BEGIN TRAN;

-- Delete old pools that have been removed
DELETE r FROM radippool r
  LEFT JOIN #radippool_temp t ON r.pool_name = t.pool_name AND r.framedipaddress = t.framedipaddress
      WHERE t.id IS NULL;

-- Add new pools that have been created
INSERT INTO radippool (pool_name,framedipaddress)
  SELECT pool_name,framedipaddress FROM #radippool_temp t WHERE NOT EXISTS (
    SELECT * FROM radippool r
    WHERE r.pool_name=t.pool_name AND r.framedipaddress=t.framedipaddress
  );

COMMIT TRAN;
END_mssql

    return %template;

}