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       Other Rules
180
181       Whitespace is automatically added between parameters:
182
183        IN:  'UPDATE', 'mytable SET', {x => 2}, 'WHERE y IN', \@colors;
184        OUT: 'UPDATE mytable SET x = ? WHERE y in (?, ?)', 2, @colors
185
186       Variables must be passed as references; otherwise, they will processed
187       as SQL fragments and interpolated verbatim into the result SQL string,
188       negating the security and performance benefits of binding values.
189
190       In contrast, any scalar values inside an arrayref or hashref are by
191       default treated as binding variables, not SQL.  The contained elements
192       may be also be sql_type() or sql().
193

Security: sql_interp_strict

195       The "sql_interp" function has a security weakness. Consider these two
196       statements, one easily a typo of the other:
197
198           sql_interp("SELECT * FROM foo WHERE a = ",\$b)
199           sql_interp("SELECT * FROM foo WHERE a = ",$b)
200
201       Both would produce valid SQL, but the first would be secure due to use
202       of bind variables, while the second is potentially insecure, because $b
203       is added directly to the SQL statement. If $b contains a malicious
204       value, it could be used for a SQL injection attack.
205
206       To prevent this accident, we also supply "sql_interp_strict()", which
207       works exactly the same as sql_interp(), but with an additional check
208       that two non-references never appear in a row . If they do, an
209       exception will be thrown.
210
211       This does mean some previously safe-but-valid SQL be need to be
212       rewritten, such as when you are building a complex query from pieces.
213       Here's a contrived example:
214
215           sql_interp("SELECT * FROM ","foo","WHERE a = ",\$b);
216
217       To work under strict mode, you need to concatenate the strings instead:
218
219           sql_interp("SELECT * FROM "."foo"."WHERE a = ",\$b);
220

A Couple Helper Functions You Sometimes Need

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

Enabling debugging output

272       To have the generated SQL and bind variables sent to STDOUT, you can
273       set the environment variable "TRACE_SQL" to "1"
274
275        TRACE_SQL=1 perl my_script.pl
276
277       Here's some example output:
278
279        DEBUG:interp[sql=INSERT INTO mytable VALUES(?),bind=5]
280

Philosophy

282       The query language is SQL.  There are other modules, such as
283       SQL::Abstract, that hide SQL behind method calls and/or Perl data
284       structures (hashes and arrays).  The former may be undesirable in some
285       cases since it replaces one language with another and hides the full
286       capabilities and expressiveness of your database's native SQL language.
287       The latter may load too much meaning into the syntax of "{, "[" and "\"
288       thereby rendering the meaning less clear:
289
290         SQL::Abstract example:
291         %where = (lname => {like => '%son%'},
292                   age   => [-and => {'>=', 10}, {'<=', 20}])
293         Plain SQL:
294         "lname LIKE '%son' AND (age >= 10 AND age <= 20)"
295
296       In contrast, SQL::Interp does not abstract away your SQL but rather
297       makes it easier to interpolate Perl variables into your SQL.  Now,
298       SQL::Interp does load some meaning into "{, "[" and "\", but we try to
299       limit its use to obvious cases.  Since your raw SQL is exposed, you can
300       use your particular dialect of SQL.
301

Limitations

303       Some types of interpolation are context-sensitive and involve
304       examination of your SQL fragments.  The examination could fail on
305       obscure syntax, but it is generally robust.  Look at the examples to
306       see the types of interpolation that are accepted, and if doubt, examine
307       the SQL output yourself with the TRACE_SQL environment variable set.
308       If needed, you can disable context sensitivity by inserting a null-
309       string before a variable.
310
311        "SET", "", \$x
312
313       A few things are just not possible with the ('WHERE', \%hashref)
314       syntax, so in such case, use a more direct syntax:
315
316         # ok--direct syntax
317         sql_interp '...WHERE', {x => $x, y => $y}, 'AND y = z';
318         # bad--trying to impose a hashref but keys must be scalars and be unique
319         sql_interp '...WHERE',
320             {sql_type(\$x) => sql('x'), y => $y, y => sql('z')};
321
322       In the cases where this module parses or generates SQL fragments, this
323       module should work for many databases, but its been tested mostly on
324       MySQL and PostgreSQL.  Please inform the author of any
325       incompatibilities.
326

Contributor and Contributing

328       David Manura (<http://math2.org/david/contact>) (author).  Mark
329       Stosberg (<http://mark.stosberg.com/>) created and maintains the
330       SQL::Interp fork. Also thanks to: Mark Tiefenbruck (syntax), Wojciech
331       Pietron (Oracle compat), Jim Chromie (DBIx::Interp idea), Juerd
332       Waalboer, Terrence Brannon (early feedback), and others.
333
334       If you like SQL::Interp, please consider supporting the project by
335       adding support for the 'quote_char' and 'name_sep' options.
336       SQL::Abstract has code that can be borrowed for this. See this bug
337       report for details: http://rt.cpan.org/Public/Bug/Display.html?id=31488
338
339       If you use SQL::Interp with PostgreSQL and are interested in a further
340       performance improvement, considering working on this optimization:
341       "RT#39778: wish: optimize IN() to be ANY() for compatible PostgreSQL
342       versions": https://rt.cpan.org/Ticket/Display.html?id=39778
343
344       SQL::Interp now has a code repository hosted on Github:
345
346        L<https://github.com/markstos/SQL-Interp>
347

Bug Reporting

349       Use rt.cpan.org for bug reports.
350

License

352       Copyright (c) 2003-2005, David Manura.  This module is free software.
353       It may be used, redistributed and/or modified under the same terms as
354       Perl itself.  See <http://www.perl.com/perl/misc/Artistic.html>.
355

See Also

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