1SQL::Interp(3)        User Contributed Perl Documentation       SQL::Interp(3)
2
3
4

NAME

6       SQL::Interp - Interpolate Perl variables into SQL statements
7

SYNOPSIS

9         use SQL::Interp ':all';
10
11         my ($sql, @bind) = sql_interp 'INSERT INTO table', \%item;
12         my ($sql, @bind) = sql_interp 'UPDATE table SET',  \%item, 'WHERE y <> ', \2;
13         my ($sql, @bind) = sql_interp 'DELETE FROM table WHERE y = ', \2;
14
15         # These two select syntax produce the same result
16         my ($sql, @bind) = sql_interp 'SELECT * FROM table WHERE x = ', \$s, 'AND y IN', \@v;
17         my ($sql, @bind) = sql_interp 'SELECT * FROM table WHERE', {x => $s, y => \@v};
18

DESCRIPTION

20       SQL::Interp converts a list of intermixed SQL fragments and variable
21       references into a conventional SQL string and list of bind values
22       suitable for passing onto DBI. This simple technique creates database
23       calls that are simpler to create and easier to read, while still giving
24       you full access to custom SQL.
25
26       SQL::Interp properly binds or escapes variables.  This recommended
27       practice safeguards against "SQL injection" attacks. The DBI
28       documentation has several links on the topic.
29
30       Besides the simple techniques shown above, The SQL::Interp integrates
31       directly with DBIx::Simple for an excellent alternative to raw DBI
32       access:
33
34         use DBIx::Simple;
35
36         ...
37
38         my $rows = $db->iquery("
39             SELECT title
40                 FROM threads
41                 WHERE date > ",\$x," AND subject IN ",\@subjects
42          )->arrays;
43
44       Since DBIx::Simple still allows you complete access to the DBI API,
45       using it as wrapper is recommended for most applications.
46

The One Function You Really Need

48   "sql_interp"
49         ($sql, @bind) = sql_interp @params;
50
51       "sql_interp()" is the one central function you need to know.
52       "sql_interp()" strings together the given list of elements  and returns
53       both an SQL string ($sql) with placeholders ("?") and a corresponding
54       list of bind values (@bind) suitable for passing to DBI.
55
56       The interpolation list can contain elements of these types:
57
58       * SQL - string containing a raw SQL fragment such as 'SELECT * FROM
59       mytable WHERE'.
60
61       * variable reference - scalarref, arrayref, hashref, or A sql_type()
62       object referring to data to interpolate between the SQL.
63
64       * other interpolation list - an interpolation list can be nested inside
65       another interpolation list.  This is possible with the sql() function.
66
67       Interpolation Examples
68
69       The following variable names will be used in the below examples:
70
71        $sref  = \3;                      # scalarref
72        $aref  = [1, 2];                  # arrayref
73        $href  = {m => 1, n => undef};    # hashref
74        $hv = {v => $v, s => $$s};        # hashref containing arrayref
75        $vv = [$v, $v];                   # arrayref of arrayref
76        $vh = [$h, $h];                   # arrayref of hashref
77
78        Let $x stand for any of these.
79
80       Default scalarref behavior
81
82       A scalarref becomes a single bind value.
83
84         IN:  'foo', $sref, 'bar'
85         OUT: 'foo ? bar', $$sref
86
87       Default hashref behavior
88
89       A hashref becomes a logical AND
90
91         IN:  'WHERE', $href
92         OUT: 'WHERE (m=? AND n IS NULL)', $h->{m},
93
94         IN:  'WHERE', $hv
95         OUT: 'WHERE (v IN (?, ?) AND s = ?)', @$v, $$s
96
97       Default arrayref of (hashref or arrayref) behavior
98
99       This is not commonly used.
100
101         IN:  $vv
102         OUT: '(SELECT ?, ? UNION ALL SELECT ?, ?)',
103                 map {@$_} @$v
104
105         IN:  $vh
106         OUT: '(SELECT ? as m, ? as n UNION ALL
107                   SELECT ?, ?)',
108                 $vh->[0]->{m}, $vh->[0]->{n},
109                 $vh->[1]->{m}, $vh->[1]->{n}
110
111         # Typical usage:
112         IN: $x
113         IN: $x, 'UNION [ALL|DISTINCT]', $x
114         IN: 'INSERT INTO mytable', $x
115         IN: 'SELECT * FROM mytable WHERE x IN', $x
116
117       Context ('IN', $x)
118
119       A scalarref or arrayref can used to form an "IN" clause.  As a
120       convenience, a reference to an arrayref is also accepted.  This way,
121       you can simply provide a reference to a value which may be a single-
122       valued scalar or a multi-valued arrayref.
123
124         IN:  'WHERE x IN', $aref
125         OUT: 'WHERE x IN (?, ?)', @$aref
126
127         IN:  'WHERE x IN', $sref
128         OUT: 'WHERE x IN (?)', $$sref
129
130         IN:  'WHERE x IN', []
131         OUT: 'WHERE 1=0'
132
133         IN:  'WHERE x NOT IN', []
134         OUT: 'WHERE 1=1'
135
136       Context ('INSERT INTO tablename', $x)
137
138         IN:  'INSERT INTO mytable', $href
139         OUT: 'INSERT INTO mytable (m, n) VALUES(?, ?)', $href->{m}, $href->{n}
140
141         IN:  'INSERT INTO mytable', $aref
142         OUT: 'INSERT INTO mytable VALUES(?, ?)', @$aref;
143
144         IN:  'INSERT INTO mytable', $sref
145         OUT: 'INSERT INTO mytable VALUES(?)', $$sref;
146
147       MySQL's "REPLACE INTO" is supported the same way.
148
149       Context ('SET', $x)
150
151         IN:  'UPDATE mytable SET', $href
152         OUT: 'UPDATE mytable SET m = ?, n = ?', $href->{m}, $href->{n}
153
154       MySQL's "ON DUPLICATE KEY UPDATE" is supported the same way.
155
156       Context ('FROM | JOIN', $x)
157
158       This is not commonly used.
159
160         IN:  'SELECT * FROM', $vv
161         OUT: 'SELECT * FROM
162              (SELECT ?, ? UNION ALL SELECT ?, ?) as t001',
163              map {@$_} @$v
164
165         IN:  'SELECT * FROM', $vh
166         OUT: 'SELECT * FROM
167              (SELECT ? as m, ? as n UNION ALL SELECT ?, ?) as temp001',
168              $vh->[0]->{m}, $vh->[0]->{n},
169              $vh->[1]->{m}, $vh->[1]->{n}
170
171         IN:  'SELECT * FROM', $vv, 'AS t'
172         OUT: 'SELECT * FROM
173              (SELECT ?, ? UNION ALL SELECT ?, ?) AS t',
174              map {@$_} @$v
175
176         # Example usage (where $x and $y are table references):
177         'SELECT * FROM', $x, 'JOIN', $y
178
179       Context ('ARRAY', $x)
180
181       A scalarref or arrayref can be turned into an array value. Such values
182       are supported by PostgreSQL.
183
184         IN:  'SELECT ARRAY', $aref
185         OUT: 'SELECT ARRAY[?, ?]', @$aref
186
187         IN:  'SELECT ARRAY', $sref
188         OUT: 'SELECT ARRAY[?]', $$sref
189
190         IN:  'SELECT ARRAY', []
191         OUT: 'SELECT ARRAY[]'
192
193       Other Rules
194
195       Whitespace is automatically added between parameters:
196
197        IN:  'UPDATE', 'mytable SET', {x => 2}, 'WHERE y IN', \@colors;
198        OUT: 'UPDATE mytable SET x = ? WHERE y in (?, ?)', 2, @colors
199
200       Variables must be passed as references; otherwise, they will processed
201       as SQL fragments and interpolated verbatim into the result SQL string,
202       negating the security and performance benefits of binding values.
203
204       In contrast, any scalar values inside an arrayref or hashref are by
205       default treated as binding variables, not SQL.  The contained elements
206       may be also be sql_type() or sql().
207

Security: sql_interp_strict

209       The "sql_interp" function has a security weakness. Consider these two
210       statements, one easily a typo of the other:
211
212           sql_interp("SELECT * FROM foo WHERE a = ",\$b)
213           sql_interp("SELECT * FROM foo WHERE a = ",$b)
214
215       Both would produce valid SQL, but the first would be secure due to use
216       of bind variables, while the second is potentially insecure, because $b
217       is added directly to the SQL statement. If $b contains a malicious
218       value, it could be used for a SQL injection attack.
219
220       To prevent this accident, we also supply "sql_interp_strict()", which
221       works exactly the same as sql_interp(), but with an additional check
222       that two non-references never appear in a row . If they do, an
223       exception will be thrown.
224
225       This does mean some previously safe-but-valid SQL be need to be
226       rewritten, such as when you are building a complex query from pieces.
227       Here's a contrived example:
228
229           sql_interp("SELECT * FROM ","foo","WHERE a = ",\$b);
230
231       To work under strict mode, you need to concatenate the strings instead:
232
233           sql_interp("SELECT * FROM "."foo"."WHERE a = ",\$b);
234
235       Note that strict mode only checks the immediate arguments of
236       "sql_interp_strict()", it does not check nested interpolation using the
237       "sql()" function (described below). Thus, the previous example can also
238       be written as:
239
240           sql_interp(sql("SELECT * FROM ","foo","WHERE a = "),\$b);
241

A Couple Helper Functions You Sometimes Need

243   "sql()"
244         sql_interp 'INSERT INTO mytable',
245             {x => $x, y => sql('CURRENT_TIMESTAMP')};
246         # OUT: 'INSERT INTO mytable (x, y) VALUES(?, CURRENT_TIMESTAMP)', $x
247
248       sql() is useful if you want insert raw SQL as a value in an arrayref or
249       hashref.
250
251   "sql_type()"
252         my $sqlvar = sql_type($value_ref, type => $sql_type, %params);
253
254       "sql_type()" provides a general way to represent a binding variable
255       along with metadata.  It is necessary in rare applications which you
256       need to explicity give the bind type of a SQL variable.
257
258       $value_ref - variable reference contained
259
260       $sql_type - any DBI SQL_DATA_TYPE (e.g. SQL_INTEGER).  Optional.
261       Default is undef.
262
263       Any other named parameters (%params) passed in will be saved into the
264       object as attributes.
265
266       sql_type objects are useful only in special cases where additional
267       information should be tagged onto the variable.  For example, DBI
268       allows bind variables to be given an explicit type:
269
270         my ($sql, @bind) = sql_interp 'SELECT * FROM mytable WHERE',
271             'x=', \$x, 'AND y=', sql_type(\$y, SQL_VARCHAR), 'AND z IN',
272             sql_type([1, 2], SQL_INTEGER);
273         # RESULT: @bind =
274         #   ([$x, sql_type(\$x)], [$y, sql_type(\$y, type => SQL_VARCHAR)],
275         #    [1, sql_type([1, 2], type => SQL_INTEGER)],
276         #    [2, sql_type([1, 2], type => SQL_INTEGER)]);
277
278         my $idx = 1;
279         for my $var (@bind) {
280             $sth->bind_param($idx++, $var->[0], $var->[1]->{type});
281         }
282         $sth->execute();
283         my $ret = $sth->selectall_arrayref();
284
285       If the interpolation list contains at least one sql_type object, then
286       all the variable references are transparently converted into sql_type
287       objects, and the elements of @bind take a special form: an arrayref
288       consisting of the bind value and the sql_type object that generated the
289       bind value.  Note that a single sql_type holding an aggregate (arrayref
290       or hashref) may generate multiple bind values.
291

Enabling debugging output

293       To have the generated SQL and bind variables sent to STDOUT, you can
294       set the environment variable "TRACE_SQL" to "1"
295
296        TRACE_SQL=1 perl my_script.pl
297
298       Here's some example output:
299
300        DEBUG:interp[sql=INSERT INTO mytable VALUES(?),bind=5]
301

Philosophy

303       The query language is SQL.  There are other modules, such as
304       SQL::Abstract, that hide SQL behind method calls and/or Perl data
305       structures (hashes and arrays).  The former may be undesirable in some
306       cases since it replaces one language with another and hides the full
307       capabilities and expressiveness of your database's native SQL language.
308       The latter may load too much meaning into the syntax of "{, "[" and "\"
309       thereby rendering the meaning less clear:
310
311         SQL::Abstract example:
312         %where = (lname => {like => '%son%'},
313                   age   => [-and => {'>=', 10}, {'<=', 20}])
314         Plain SQL:
315         "lname LIKE '%son' AND (age >= 10 AND age <= 20)"
316
317       In contrast, SQL::Interp does not abstract away your SQL but rather
318       makes it easier to interpolate Perl variables into your SQL.  Now,
319       SQL::Interp does load some meaning into "{, "[" and "\", but we try to
320       limit its use to obvious cases.  Since your raw SQL is exposed, you can
321       use your particular dialect of SQL.
322

Limitations

324       Some types of interpolation are context-sensitive and involve
325       examination of your SQL fragments.  The examination could fail on
326       obscure syntax, but it is generally robust.  Look at the examples to
327       see the types of interpolation that are accepted, and if doubt, examine
328       the SQL output yourself with the TRACE_SQL environment variable set.
329       If needed, you can disable context sensitivity by inserting a null-
330       string before a variable.
331
332        "SET", "", \$x
333
334       A few things are just not possible with the ('WHERE', \%hashref)
335       syntax, so in such case, use a more direct syntax:
336
337         # ok--direct syntax
338         sql_interp '...WHERE', {x => $x, y => $y}, 'AND y = z';
339         # bad--trying to impose a hashref but keys must be scalars and be unique
340         sql_interp '...WHERE',
341             {sql_type(\$x) => sql('x'), y => $y, y => sql('z')};
342
343       In the cases where this module parses or generates SQL fragments, this
344       module should work for many databases, but its been tested mostly on
345       MySQL and PostgreSQL.  Please inform the author of any
346       incompatibilities.
347

Contributor and Contributing

349       David Manura is the author of the original SQL::Interpolate, Mark
350       Stosberg (<http://mark.stosberg.com/>) created the SQL::Interp fork. It
351       is now maintained by Yoran Heling (<https://yorhel.nl/>).
352
353       Also thanks to: Mark Tiefenbruck (syntax), Wojciech Pietron (Oracle
354       compat), Jim Chromie (DBIx::Interp idea), Juerd Waalboer, Terrence
355       Brannon (early feedback), and others.
356
357       The SQL::Interp Git repository is hosted at
358       <https://code.blicky.net/yorhel/SQL-Interp>.
359

License

361       Copyright (c) 2004-2005 David Manura.
362
363       Copyright (c) 2005-2019 Mark Stosberg.
364
365       Copyright (c) 2019-2021 Yoran Heling.
366
367       This module is free software. It may be used, redistributed and/or
368       modified under the same terms as Perl itself.  See
369       <http://www.perl.com/perl/misc/Artistic.html>.
370

See Also

372   Fork
373       This module was forked from SQL::Interpolate, around version 0.40.  The
374       core functionality remains unchanged, but the following  incompatible
375       changes have been made:
376
377       •   The optional source filtering feature was removed.
378
379       •   The optional "macro" feature was removed.
380
381       •   A legacy, deprecated function "sql_literal" was removed.
382
383       •   The docs were overhauled to be simpler and clearer.
384
385       So if you want those removed features, you should use SQL::Interpolate.
386       I used it for years without those optional features and never missed
387       them.
388
389   Other modules in this distribution
390       DBIx::Interp allows DBI methods to accept an "sql_interp()"-like
391       interpolation list rather than the traditional ($statement, \%attr,
392       @bind_values) parameter list. However, consider using DBIx::Simple
393       instead-- it even more user friendly.
394
395   Related modules
396       SQL::Abstract
397
398       SQL::Abstract shares with "SQL::Interp" the purpose of making SQL
399       generation easier. SQL::Abstract differs in that it expresses queries
400       in terms of OO method calls. It's syntax may impair readability because
401       it uses the subtle difference between a brace and bracket to denote the
402       difference between AND and OR in a query (the user can change whether a
403       bracket implies "AND" or "OR"). Some complex where clauses are
404       difficult or impossible with SQL::Abstract.  SQL::Interp gives the
405       author more direct access to the underlying SQL.  This permits using
406       the full expressivity of the database query language.
407
408       DBIx::Simple
409
410       DBIx::Simple strives to simplify SQL generation as well as the data
411       structures returned from DBI. "DBIx::Simple" currently can use
412       SQL::Interp to help generate SQL.
413
414       Class::DBI
415
416       Class::DBI is a popular "complete" solution for abstract database
417       access through an OO interface. It currently has a plugin called
418       Class::DBI::AbstractSearch that allows it to use "SQL::Abstract" to
419       generate SQL. It's possible that "SQL::Interp" could be integrated with
420       it as well.
421
422       SQL::Preproc
423
424       SQL::Preproc provides an "embedded SQL" approach where the Perl and SQL
425       languages are extended (via source filtering) to support interwoven
426       Perl and SQL.  The syntax supports interpolating Perl variables into
427       SQL and passing query results back into Perl variables.  In contrast,
428       SQL::Interp extends neither SQL nor Perl, and it deals only with
429       interpolating Perl variables into queries, whereas returning variables
430       from queries is the job of something like DBI, DBIx::Interp, or
431       DBIx::Simple.
432
433       SQL::String
434
435       SQL::String shares a number of similiarities to SQL::Interp but it is
436       more rudimentary.  Both let you combine "chunks" of SQL that have their
437       parameters attached to them and then transform it into an SQL string
438       and list of bind parameters suitable for passing to DBI.
439
440       SQL::KeywordSearch
441
442       SQL::KeywordSearch helps generate SQL for a keyword search.  It can
443       return the result in a format compatible with SQL::Interp to become
444       part of a larger query.
445
446
447
448perl v5.34.0                      2021-07-22                    SQL::Interp(3)
Impressum