1SQL::SplitStatement(3)User Contributed Perl DocumentationSQL::SplitStatement(3)
2
3
4
6 SQL::SplitStatement - Split any SQL code into atomic statements
7
9 # Multiple SQL statements in a single string
10 my $sql_code = <<'SQL';
11 CREATE TABLE parent(a, b, c , d );
12 CREATE TABLE child (x, y, "w;", "z;z");
13 /* C-style comment; */
14 CREATE TRIGGER "check;delete;parent;" BEFORE DELETE ON parent WHEN
15 EXISTS (SELECT 1 FROM child WHERE old.a = x AND old.b = y)
16 BEGIN
17 SELECT RAISE(ABORT, 'constraint failed;'); -- Inline SQL comment
18 END;
19 -- Standalone SQL; comment; with semicolons;
20 INSERT INTO parent (a, b, c, d) VALUES ('pippo;', 'pluto;', NULL, NULL);
21 SQL
22
23 use SQL::SplitStatement;
24
25 my $sql_splitter = SQL::SplitStatement->new;
26 my @statements = $sql_splitter->split($sql_code);
27
28 # @statements now is:
29 #
30 # (
31 # 'CREATE TABLE parent(a, b, c , d )',
32 # 'CREATE TABLE child (x, y, "w;", "z;z")',
33 # 'CREATE TRIGGER "check;delete;parent;" BEFORE DELETE ON parent WHEN
34 # EXISTS (SELECT 1 FROM child WHERE old.a = x AND old.b = y)
35 # BEGIN
36 # SELECT RAISE(ABORT, \'constraint failed;\');
37 # END',
38 # 'INSERT INTO parent (a, b, c, d) VALUES (\'pippo;\', \'pluto;\', NULL, NULL)'
39 # )
40
42 This is a simple module which tries to split any SQL code, even
43 including non-standard extensions (for the details see the "SUPPORTED
44 DBMSs" section below), into the atomic statements it is composed of.
45
46 The logic used to split the SQL code is more sophisticated than a raw
47 "split" on the ";" (semicolon) character: first, various different
48 statement terminator tokens are recognized (see below for the list),
49 then this module is able to correctly handle the presence of said
50 tokens inside identifiers, values, comments, "BEGIN ... END" blocks
51 (even nested), dollar-quoted strings, MySQL custom "DELIMITER"s,
52 procedural code etc., as (partially) exemplified in the "SYNOPSIS"
53 above.
54
55 Consider however that this is by no means a validating parser
56 (technically speaking, it's just a context-sensitive tokenizer). It
57 should rather be seen as an in-progress heuristic approach, which will
58 gradually improve as test cases will be reported. This also means that,
59 except for the "LIMITATIONS" detailed below, there is no known (to the
60 author) SQL code the most current release of this module can't
61 correctly split.
62
63 The test suite bundled with the distribution (which now includes the
64 popular Sakila and Pagila sample db schemata, as detailed in the
65 "SHOWCASE" section below) should give you an idea of the capabilities
66 of this module
67
68 If your atomic statements are to be fed to a DBMS, you are encouraged
69 to use DBIx::MultiStatementDo instead, which uses this module and also
70 (optionally) offers automatic transactions support, so that you'll have
71 the all-or-nothing behavior you would probably want.
72
74 "new"
75 • "SQL::SplitStatement->new( %options )"
76
77 • "SQL::SplitStatement->new( \%options )"
78
79 It creates and returns a new SQL::SplitStatement object. It accepts its
80 options either as a hash or a hashref.
81
82 "new" takes the following Boolean options, which for documentation
83 purposes can be grouped in two sets: "Formatting Options" and "DBMSs
84 Specific Options".
85
86 Formatting Options
87
88 • "keep_terminators"
89
90 A Boolean option which causes, when set to a false value (which is
91 the default), the trailing terminator token to be discarded in the
92 returned atomic statements. When set to a true value, the
93 terminators are kept instead.
94
95 The possible terminators (which are treated as such depending on
96 the context) are:
97
98 • ";" (the semicolon character);
99
100 • any string defined by the MySQL "DELIMITER" command;
101
102 • an ";" followed by an "/" (forward-slash character) on its own
103 line;
104
105 • an ";" followed by an "." (dot character) on its own line,
106 followed by an "/" on its own line;
107
108 • an "/" on its own line regardless of the preceding characters
109 (only if the "slash_terminates" option, explained below, is
110 set).
111
112 The multi-line terminators above are always treated as a single
113 token, that is they are discarded (or returned) as a whole
114 (regardless of the "slash_terminates" option value).
115
116 If your statements are to be fed to a DBMS, you are advised to keep
117 this option to its default (false) value, since some drivers/DBMSs
118 don't want the terminator to be present at the end of the (single)
119 statement.
120
121 (Note that the last, possibly empty, statement of a given SQL text,
122 never has a trailing terminator. See below for an example.)
123
124 • "keep_terminator"
125
126 An alias for the the "keep_terminators" option explained above.
127 Note that if "keep_terminators" and "keep_terminator" are both
128 passed to "new", an exception is thrown.
129
130 • "keep_extra_spaces"
131
132 A Boolean option which causes, when set to a false value (which is
133 the default), the spaces ("\s") around the statements to be
134 trimmed. When set to a true value, these spaces are kept instead.
135
136 When "keep_terminators" is set to false as well, the terminator is
137 discarded first (regardless of the spaces around it) and the
138 trailing spaces are trimmed then. This ensures that if
139 "keep_extra_spaces" is set to false, the returned statements will
140 never have trailing (nor leading) spaces, regardless of the
141 "keep_terminators" value.
142
143 • "keep_comments"
144
145 A Boolean option which causes, when set to a false value (which is
146 the default), the comments to be discarded in the returned
147 statements. When set to a true value, they are kept with the
148 statements instead.
149
150 Both SQL and multi-line C-style comments are recognized.
151
152 When kept, each comment is returned in the same string with the
153 atomic statement it belongs to. A comment belongs to a statement if
154 it appears, in the original SQL code, before the end of that
155 statement and after the terminator of the previous statement (if it
156 exists), as shown in this pseudo-SQL snippet:
157
158 /* This comment
159 will be returned
160 together with statement1 */
161
162 <statement1>; -- This will go with statement2
163 -- (note the semicolon which closes statement1)
164
165 <statement2>
166 -- This with statement2 as well
167
168 • "keep_empty_statements"
169
170 A Boolean option which causes, when set to a false value (which is
171 the default), the empty statements to be discarded. When set to a
172 true value, the empty statements are returned instead.
173
174 A statement is considered empty when it contains no characters
175 other than the terminator and space characters ("\s").
176
177 A statement composed solely of comments is not recognized as empty
178 and may therefore be returned even when "keep_empty_statements" is
179 false. To avoid this, it is sufficient to leave "keep_comments" to
180 false as well.
181
182 Note instead that an empty statement is recognized as such
183 regardless of the value of the options "keep_terminators" and
184 "keep_extra_spaces".
185
186 These options are basically to be kept to their default (false) values,
187 especially if the atomic statements are to be given to a DBMS.
188
189 They are intended mainly for cosmetic reasons, or if you want to count
190 by how many atomic statements, including the empty ones, your original
191 SQL code was composed of.
192
193 Another situation where they are useful (in the general case necessary,
194 really), is when you want to retain the ability to verbatim rebuild the
195 original SQL string from the returned statements:
196
197 my $verbatim_splitter = SQL::SplitStatement->new(
198 keep_terminators => 1,
199 keep_extra_spaces => 1,
200 keep_comments => 1,
201 keep_empty_statements => 1
202 );
203
204 my @verbatim_statements = $verbatim_splitter->split($sql_string);
205
206 $sql_string eq join '', @verbatim_statements; # Always true, given the constructor above.
207
208 Other than this, again, you are recommended to stick with the defaults.
209
210 DBMSs Specific Options
211
212 The same syntactic structure can have different semantics across
213 different SQL dialects, so sometimes it is necessary to help the parser
214 to make the right decision. This is the function of these options.
215
216 • "slash_terminates"
217
218 A Boolean option which causes, when set to a true value (which is
219 the default), a "/" (forward-slash) on its own line, even without a
220 preceding semicolon, to be admitted as a (possible) terminator.
221
222 If set to false, a forward-slash on its own line is treated as a
223 statement terminator only if preceded by a semicolon or by a dot
224 and a semicolon.
225
226 If you are dealing with Oracle's SQL, you should let this option
227 set, since a slash (alone, without a preceding semicolon) is
228 sometimes used as a terminator, as it is permitted by SQL*Plus (on
229 non-block statements).
230
231 With SQL dialects other than Oracle, there is the (theoretical)
232 possibility that a slash on its own line can pass the additional
233 checks and be considered a terminator (while it shouldn't). This
234 chance should be really tiny (it has never been observed in real
235 world code indeed). Though negligible, by setting this option to
236 false that risk can anyway be ruled out.
237
238 "split"
239 • "$sql_splitter->split( $sql_string )"
240
241 This is the method which actually splits the SQL code into its atomic
242 components.
243
244 It returns a list containing the atomic statements, in the same order
245 they appear in the original SQL code. The atomic statements are
246 returned according to the options explained above.
247
248 Note that, as mentioned above, an SQL string which terminates with a
249 terminator token (for example a semicolon), contains a trailing empty
250 statement: this is correct and it is treated accordingly (if
251 "keep_empty_statements" is set to a true value):
252
253 my $sql_splitter = SQL::SplitStatement->new(
254 keep_empty_statements => 1
255 );
256
257 my @statements = $sql_splitter->split( 'SELECT 1;' );
258
259 print 'The SQL code contains ' . scalar(@statements) . ' statements.';
260 # The SQL code contains 2 statements.
261
262 "split_with_placeholders"
263 • "$sql_splitter->split_with_placeholders( $sql_string )"
264
265 It works exactly as the "split" method explained above, except that it
266 returns also a list of integers, each of which is the number of the
267 placeholders contained in the corresponding atomic statement.
268
269 More precisely, its return value is a list of two elements, the first
270 of which is a reference to the list of the atomic statements exactly as
271 returned by the "split" method, while the second is a reference to the
272 list of the number of placeholders as explained above.
273
274 Here is an example:
275
276 # 4 statements (valid SQLite SQL)
277 my $sql_code = <<'SQL';
278 CREATE TABLE state (id, name);
279 INSERT INTO state (id, name) VALUES (?, ?);
280 CREATE TABLE city (id, name, state_id);
281 INSERT INTO city (id, name, state_id) VALUES (?, ?, ?)
282 SQL
283
284 my $splitter = SQL::SplitStatement->new;
285
286 my ( $statements, $placeholders )
287 = $splitter->split_with_placeholders( $sql_code );
288
289 # $placeholders now is: [0, 2, 0, 3]
290
291 where the returned $placeholders list(ref) is to be read as follows:
292 the first statement contains 0 placeholders, the second 2, the third 0
293 and the fourth 3.
294
295 The recognized placeholders are:
296
297 • question mark placeholders, represented by the "?" character;
298
299 • dollar sign numbered placeholders, represented by the "$1, $2, ...,
300 $n" strings;
301
302 • named parameters, such as ":foo", ":bar", ":baz" etc.
303
304 "keep_terminators"
305 • "$sql_splitter->keep_terminators"
306
307 • "$sql_splitter->keep_terminators( $boolean )"
308
309 Getter/setter method for the "keep_terminators" option explained
310 above.
311
312 "keep_terminator"
313 An alias for the "keep_terminators" method explained above.
314
315 "keep_extra_spaces"
316 • "$sql_splitter->keep_extra_spaces"
317
318 • "$sql_splitter->keep_extra_spaces( $boolean )"
319
320 Getter/setter method for the "keep_extra_spaces" option explained
321 above.
322
323 "keep_comments"
324 • "$sql_splitter->keep_comments"
325
326 • "$sql_splitter->keep_comments( $boolean )"
327
328 Getter/setter method for the "keep_comments" option explained
329 above.
330
331 "keep_empty_statements"
332 • "$sql_splitter->keep_empty_statements"
333
334 • "$sql_splitter->keep_empty_statements( $boolean )"
335
336 Getter/setter method for the "keep_empty_statements" option
337 explained above.
338
339 "slash_terminates"
340 • "$sql_splitter->slash_terminates"
341
342 • "$sql_splitter->slash_terminates( $boolean )"
343
344 Getter/setter method for the "slash_terminates" option explained
345 above.
346
348 SQL::SplitStatement aims to cover the widest possible range of DBMSs,
349 SQL dialects and extensions (even proprietary), in a (nearly) fully
350 transparent way for the user.
351
352 Currently it has been tested mainly on SQLite, PostgreSQL, MySQL and
353 Oracle.
354
355 Procedural Extensions
356 Procedural code is by far the most complex to handle.
357
358 Currently any block of code which start with "FUNCTION", "PROCEDURE",
359 "DECLARE", "CREATE" or "CALL" is correctly recognized, as well as
360 anonymous "BEGIN ... END" blocks, dollar quoted blocks and blocks
361 delimited by a "DELIMITER"-defined custom terminator, therefore a wide
362 range of procedural extensions should be handled correctly. However,
363 only PL/SQL, PL/PgSQL and MySQL code has been tested so far.
364
365 If you need also other procedural languages to be recognized, please
366 let me know (possibly with some test cases).
367
369 Bound to be plenty, given the heuristic nature of this module (and its
370 ambitious goals). However, no limitations are currently known.
371
372 Please report any problematic test case.
373
374 Non-limitations
375 To be split correctly, the given input must, in general, be
376 syntactically valid SQL. For example, an unbalanced "BEGIN" or a
377 misspelled keyword could, under certain circumstances, confuse the
378 parser and make it trip over the next statement terminator, thus
379 returning non-split statements. This should not be seen as a
380 limitation though, as the original (invalid) SQL code would have been
381 unusable anyway (remember that this is NOT a validating parser!)
382
384 To test the capabilities of this module, you can run it (or rather run
385 sql-split) on the files t/data/sakila-schema.sql and
386 t/data/pagila-schema.sql included in the distribution, which contain
387 two quite large and complex real world db schemata, for MySQL and
388 PostgreSQL respectively.
389
390 For more information:
391
392 • Sakila db: <http://dev.mysql.com/doc/sakila/en/sakila.html>
393
394 • Pagila db: <http://pgfoundry.org/projects/dbsamples>
395
397 SQL::SplitStatement depends on the following modules:
398
399 • Carp
400
401 • Class::Accessor::Fast
402
403 • List::MoreUtils
404
405 • Regexp::Common
406
407 • SQL::Tokenizer 0.22 or newer
408
410 Emanuele Zeppieri, "<emazep@cpan.org>"
411
413 No known bugs.
414
415 Please report any bugs or feature requests to "bug-sql-SplitStatement
416 at rt.cpan.org", or through the web interface at
417 <http://rt.cpan.org/NoAuth/ReportBug.html?Queue=SQL-SplitStatement>. I
418 will be notified, and then you'll automatically be notified of progress
419 on your bug as I make changes.
420
422 You can find documentation for this module with the perldoc command:
423
424 perldoc SQL::SplitStatement
425
426 You can also look for information at:
427
428 • AnnoCPAN: Annotated CPAN documentation
429
430 <http://annocpan.org/dist/SQL-SplitStatement>
431
432 • CPAN Ratings
433
434 <http://cpanratings.perl.org/d/SQL-SplitStatement>
435
436 • On MetaCPAN
437
438 <https://metacpan.org/pod/SQL::SplitStatement/>
439
441 Igor Sutton for his excellent SQL::Tokenizer, which made writing this
442 module a joke.
443
445 • DBIx::MultiStatementDo
446
447 • sql-split
448
450 Copyright 2010-2011 Emanuele Zeppieri.
451
452 This program is free software; you can redistribute it and/or modify it
453 under the terms of either: the GNU General Public License as published
454 by the Free Software Foundation, or the Artistic License.
455
456 See http://dev.perl.org/licenses/ for more information.
457
458
459
460perl v5.38.0 2023-07-21 SQL::SplitStatement(3)