1DBI(3)                User Contributed Perl Documentation               DBI(3)
2
3
4

NAME

6       DBI - Database independent interface for Perl
7

SYNOPSIS

9         use DBI;
10
11         @driver_names = DBI->available_drivers;
12         %drivers      = DBI->installed_drivers;
13         @data_sources = DBI->data_sources($driver_name, \%attr);
14
15         $dbh = DBI->connect($data_source, $username, $auth, \%attr);
16
17         $rv  = $dbh->do($statement);
18         $rv  = $dbh->do($statement, \%attr);
19         $rv  = $dbh->do($statement, \%attr, @bind_values);
20
21         $ary_ref  = $dbh->selectall_arrayref($statement);
22         $hash_ref = $dbh->selectall_hashref($statement, $key_field);
23
24         $ary_ref  = $dbh->selectcol_arrayref($statement);
25         $ary_ref  = $dbh->selectcol_arrayref($statement, \%attr);
26
27         @row_ary  = $dbh->selectrow_array($statement);
28         $ary_ref  = $dbh->selectrow_arrayref($statement);
29         $hash_ref = $dbh->selectrow_hashref($statement);
30
31         $sth = $dbh->prepare($statement);
32         $sth = $dbh->prepare_cached($statement);
33
34         $rc = $sth->bind_param($p_num, $bind_value);
35         $rc = $sth->bind_param($p_num, $bind_value, $bind_type);
36         $rc = $sth->bind_param($p_num, $bind_value, \%attr);
37
38         $rv = $sth->execute;
39         $rv = $sth->execute(@bind_values);
40         $rv = $sth->execute_array(\%attr, ...);
41
42         $rc = $sth->bind_col($col_num, \$col_variable);
43         $rc = $sth->bind_columns(@list_of_refs_to_vars_to_bind);
44
45         @row_ary  = $sth->fetchrow_array;
46         $ary_ref  = $sth->fetchrow_arrayref;
47         $hash_ref = $sth->fetchrow_hashref;
48
49         $ary_ref  = $sth->fetchall_arrayref;
50         $ary_ref  = $sth->fetchall_arrayref( $slice, $max_rows );
51
52         $hash_ref = $sth->fetchall_hashref( $key_field );
53
54         $rv  = $sth->rows;
55
56         $rc  = $dbh->begin_work;
57         $rc  = $dbh->commit;
58         $rc  = $dbh->rollback;
59
60         $quoted_string = $dbh->quote($string);
61
62         $rc  = $h->err;
63         $str = $h->errstr;
64         $rv  = $h->state;
65
66         $rc  = $dbh->disconnect;
67
68       The synopsis above only lists the major methods and parameters.
69
70   GETTING HELP
71       General
72
73       Before asking any questions, reread this document, consult the archives
74       and read the DBI FAQ. The archives are listed at the end of this
75       document and on the DBI home page <http://dbi.perl.org/support/>
76
77       You might also like to read the Advanced DBI Tutorial at
78       <http://www.slideshare.net/Tim.Bunce/dbi-advanced-tutorial-2007>
79
80       To help you make the best use of the dbi-users mailing list, and any
81       other lists or forums you may use, I recommend that you read "Getting
82       Answers" by Mike Ash: <http://mikeash.com/getting_answers.html>.
83
84       Mailing Lists
85
86       If you have questions about DBI, or DBD driver modules, you can get
87       help from the dbi-users@perl.org mailing list. This is the best way to
88       get help. You don't have to subscribe to the list in order to post,
89       though I'd recommend it. You can get help on subscribing and using the
90       list by emailing dbi-users-help@perl.org.
91
92       Please note that Tim Bunce does not maintain the mailing lists or the
93       web pages (generous volunteers do that).  So please don't send mail
94       directly to him; he just doesn't have the time to answer questions
95       personally. The dbi-users mailing list has lots of experienced people
96       who should be able to help you if you need it. If you do email Tim he
97       is very likely to just forward it to the mailing list.
98
99       IRC
100
101       DBI IRC Channel: #dbi on irc.perl.org (<irc://irc.perl.org/#dbi>)
102
103       Online
104
105       StackOverflow has a DBI tag
106       <http://stackoverflow.com/questions/tagged/dbi> with over 800
107       questions.
108
109       The DBI home page at <http://dbi.perl.org/> and the DBI FAQ at
110       <http://faq.dbi-support.com/> may be worth a visit.  They include links
111       to other resources, but are rather out-dated.
112
113       Reporting a Bug
114
115       If you think you've found a bug then please read "How to Report Bugs
116       Effectively" by Simon Tatham:
117       <http://www.chiark.greenend.org.uk/~sgtatham/bugs.html>.
118
119       If you think you've found a memory leak then read "Memory Leaks".
120
121       Your problem is most likely related to the specific DBD driver module
122       you're using. If that's the case then click on the 'Bugs' link on the
123       <http://metacpan.org> page for your driver. Only submit a bug report
124       against the DBI itself if you're sure that your issue isn't related to
125       the driver you're using.
126
127   NOTES
128       This is the DBI specification that corresponds to DBI version 1.642
129       (see DBI::Changes for details).
130
131       The DBI is evolving at a steady pace, so it's good to check that you
132       have the latest copy.
133
134       The significant user-visible changes in each release are documented in
135       the DBI::Changes module so you can read them by executing "perldoc
136       DBI::Changes".
137
138       Some DBI changes require changes in the drivers, but the drivers can
139       take some time to catch up. Newer versions of the DBI have added
140       features that may not yet be supported by the drivers you use.  Talk to
141       the authors of your drivers if you need a new feature that is not yet
142       supported.
143
144       Features added after DBI 1.21 (February 2002) are marked in the text
145       with the version number of the DBI release they first appeared in.
146
147       Extensions to the DBI API often use the "DBIx::*" namespace.  See
148       "Naming Conventions and Name Space". DBI extension modules can be found
149       at <https://metacpan.org/search?q=DBIx>.  And all modules related to
150       the DBI can be found at <https://metacpan.org/search?q=DBI>.
151

DESCRIPTION

153       The DBI is a database access module for the Perl programming language.
154       It defines a set of methods, variables, and conventions that provide a
155       consistent database interface, independent of the actual database being
156       used.
157
158       It is important to remember that the DBI is just an interface.  The DBI
159       is a layer of "glue" between an application and one or more database
160       driver modules.  It is the driver modules which do most of the real
161       work. The DBI provides a standard interface and framework for the
162       drivers to operate within.
163
164       This document often uses terms like references, objects, methods.  If
165       you're not familiar with those terms then it would be a good idea to
166       read at least the following perl manuals first: perlreftut, perldsc,
167       perllol, and perlboot.
168
169   Architecture of a DBI Application
170                    |<- Scope of DBI ->|
171                         .-.   .--------------.   .-------------.
172         .-------.       | |---| XYZ Driver   |---| XYZ Engine  |
173         | Perl  |       | |   `--------------'   `-------------'
174         | script|  |A|  |D|   .--------------.   .-------------.
175         | using |--|P|--|B|---|Oracle Driver |---|Oracle Engine|
176         | DBI   |  |I|  |I|   `--------------'   `-------------'
177         | API   |       | |...
178         |methods|       | |... Other drivers
179         `-------'       | |...
180                         `-'
181
182       The API, or Application Programming Interface, defines the call
183       interface and variables for Perl scripts to use. The API is implemented
184       by the Perl DBI extension.
185
186       The DBI "dispatches" the method calls to the appropriate driver for
187       actual execution.  The DBI is also responsible for the dynamic loading
188       of drivers, error checking and handling, providing default
189       implementations for methods, and many other non-database specific
190       duties.
191
192       Each driver contains implementations of the DBI methods using the
193       private interface functions of the corresponding database engine.  Only
194       authors of sophisticated/multi-database applications or generic library
195       functions need be concerned with drivers.
196
197   Notation and Conventions
198       The following conventions are used in this document:
199
200         $dbh    Database handle object
201         $sth    Statement handle object
202         $drh    Driver handle object (rarely seen or used in applications)
203         $h      Any of the handle types above ($dbh, $sth, or $drh)
204         $rc     General Return Code  (boolean: true=ok, false=error)
205         $rv     General Return Value (typically an integer)
206         @ary    List of values returned from the database, typically a row of data
207         $rows   Number of rows processed (if available, else -1)
208         $fh     A filehandle
209         undef   NULL values are represented by undefined values in Perl
210         \%attr  Reference to a hash of attribute values passed to methods
211
212       Note that Perl will automatically destroy database and statement handle
213       objects if all references to them are deleted.
214
215   Outline Usage
216       To use DBI, first you need to load the DBI module:
217
218         use DBI;
219         use strict;
220
221       (The "use strict;" isn't required but is strongly recommended.)
222
223       Then you need to "connect" to your data source and get a handle for
224       that connection:
225
226         $dbh = DBI->connect($dsn, $user, $password,
227                             { RaiseError => 1, AutoCommit => 0 });
228
229       Since connecting can be expensive, you generally just connect at the
230       start of your program and disconnect at the end.
231
232       Explicitly defining the required "AutoCommit" behaviour is strongly
233       recommended and may become mandatory in a later version.  This
234       determines whether changes are automatically committed to the database
235       when executed, or need to be explicitly committed later.
236
237       The DBI allows an application to "prepare" statements for later
238       execution.  A prepared statement is identified by a statement handle
239       held in a Perl variable.  We'll call the Perl variable $sth in our
240       examples.
241
242       The typical method call sequence for a "SELECT" statement is:
243
244         prepare,
245           execute, fetch, fetch, ...
246           execute, fetch, fetch, ...
247           execute, fetch, fetch, ...
248
249       for example:
250
251         $sth = $dbh->prepare("SELECT foo, bar FROM table WHERE baz=?");
252
253         $sth->execute( $baz );
254
255         while ( @row = $sth->fetchrow_array ) {
256           print "@row\n";
257         }
258
259       The typical method call sequence for a non-"SELECT" statement is:
260
261         prepare,
262           execute,
263           execute,
264           execute.
265
266       for example:
267
268         $sth = $dbh->prepare("INSERT INTO table(foo,bar,baz) VALUES (?,?,?)");
269
270         while(<CSV>) {
271           chomp;
272           my ($foo,$bar,$baz) = split /,/;
273               $sth->execute( $foo, $bar, $baz );
274         }
275
276       The "do()" method can be used for non repeated non-"SELECT" statement
277       (or with drivers that don't support placeholders):
278
279         $rows_affected = $dbh->do("UPDATE your_table SET foo = foo + 1");
280
281       To commit your changes to the database (when "AutoCommit" is off):
282
283         $dbh->commit;  # or call $dbh->rollback; to undo changes
284
285       Finally, when you have finished working with the data source, you
286       should "disconnect" from it:
287
288         $dbh->disconnect;
289
290   General Interface Rules & Caveats
291       The DBI does not have a concept of a "current session". Every session
292       has a handle object (i.e., a $dbh) returned from the "connect" method.
293       That handle object is used to invoke database related methods.
294
295       Most data is returned to the Perl script as strings. (Null values are
296       returned as "undef".)  This allows arbitrary precision numeric data to
297       be handled without loss of accuracy.  Beware that Perl may not preserve
298       the same accuracy when the string is used as a number.
299
300       Dates and times are returned as character strings in the current
301       default format of the corresponding database engine.  Time zone effects
302       are database/driver dependent.
303
304       Perl supports binary data in Perl strings, and the DBI will pass binary
305       data to and from the driver without change. It is up to the driver
306       implementors to decide how they wish to handle such binary data.
307
308       Perl supports two kinds of strings: Unicode (utf8 internally) and non-
309       Unicode (defaults to iso-8859-1 if forced to assume an encoding).
310       Drivers should accept both kinds of strings and, if required, convert
311       them to the character set of the database being used. Similarly, when
312       fetching from the database character data that isn't iso-8859-1 the
313       driver should convert it into utf8.
314
315       Multiple SQL statements may not be combined in a single statement
316       handle ($sth), although some databases and drivers do support this
317       (notably Sybase and SQL Server).
318
319       Non-sequential record reads are not supported in this version of the
320       DBI.  In other words, records can only be fetched in the order that the
321       database returned them, and once fetched they are forgotten.
322
323       Positioned updates and deletes are not directly supported by the DBI.
324       See the description of the "CursorName" attribute for an alternative.
325
326       Individual driver implementors are free to provide any private
327       functions and/or handle attributes that they feel are useful.  Private
328       driver functions can be invoked using the DBI "func()" method.  Private
329       driver attributes are accessed just like standard attributes.
330
331       Many methods have an optional "\%attr" parameter which can be used to
332       pass information to the driver implementing the method. Except where
333       specifically documented, the "\%attr" parameter can only be used to
334       pass driver specific hints. In general, you can ignore "\%attr"
335       parameters or pass it as "undef".
336
337   Naming Conventions and Name Space
338       The DBI package and all packages below it ("DBI::*") are reserved for
339       use by the DBI. Extensions and related modules use the "DBIx::"
340       namespace (see <http://www.perl.com/CPAN/modules/by-module/DBIx/>).
341       Package names beginning with "DBD::" are reserved for use by DBI
342       database drivers.  All environment variables used by the DBI or by
343       individual DBDs begin with ""DBI_"" or ""DBD_"".
344
345       The letter case used for attribute names is significant and plays an
346       important part in the portability of DBI scripts.  The case of the
347       attribute name is used to signify who defined the meaning of that name
348       and its values.
349
350         Case of name  Has a meaning defined by
351         ------------  ------------------------
352         UPPER_CASE    Standards, e.g.,  X/Open, ISO SQL92 etc (portable)
353         MixedCase     DBI API (portable), underscores are not used.
354         lower_case    Driver or database engine specific (non-portable)
355
356       It is of the utmost importance that Driver developers only use
357       lowercase attribute names when defining private attributes. Private
358       attribute names must be prefixed with the driver name or suitable
359       abbreviation (e.g., ""ora_"" for Oracle, ""ing_"" for Ingres, etc).
360
361   SQL - A Query Language
362       Most DBI drivers require applications to use a dialect of SQL
363       (Structured Query Language) to interact with the database engine.  The
364       "Standards Reference Information" section provides links to useful
365       information about SQL.
366
367       The DBI itself does not mandate or require any particular language to
368       be used; it is language independent. In ODBC terms, the DBI is in
369       "pass-thru" mode, although individual drivers might not be. The only
370       requirement is that queries and other statements must be expressed as a
371       single string of characters passed as the first argument to the
372       "prepare" or "do" methods.
373
374       For an interesting diversion on the real history of RDBMS and SQL, from
375       the people who made it happen, see:
376
377         http://www.mcjones.org/System_R/SQL_Reunion_95/sqlr95.html
378
379       Follow the "Full Contents" then "Intergalactic dataspeak" links for the
380       SQL history.
381
382   Placeholders and Bind Values
383       Some drivers support placeholders and bind values.  Placeholders, also
384       called parameter markers, are used to indicate values in a database
385       statement that will be supplied later, before the prepared statement is
386       executed.  For example, an application might use the following to
387       insert a row of data into the SALES table:
388
389         INSERT INTO sales (product_code, qty, price) VALUES (?, ?, ?)
390
391       or the following, to select the description for a product:
392
393         SELECT description FROM products WHERE product_code = ?
394
395       The "?" characters are the placeholders.  The association of actual
396       values with placeholders is known as binding, and the values are
397       referred to as bind values.  Note that the "?" is not enclosed in
398       quotation marks, even when the placeholder represents a string.
399
400       Some drivers also allow placeholders like ":"name and ":"N (e.g., ":1",
401       ":2", and so on) in addition to "?", but their use is not portable.
402
403       If the ":"N form of placeholder is supported by the driver you're
404       using, then you should be able to use either "bind_param" or "execute"
405       to bind values. Check your driver documentation.
406
407       Some drivers allow you to prevent the recognition of a placeholder by
408       placing a single backslash character ("\") immediately before it. The
409       driver will remove the backslash character and ignore the placeholder,
410       passing it unchanged to the backend. If the driver supports this then
411       "get_info"(9000) will return true.
412
413       With most drivers, placeholders can't be used for any element of a
414       statement that would prevent the database server from validating the
415       statement and creating a query execution plan for it. For example:
416
417         "SELECT name, age FROM ?"         # wrong (will probably fail)
418         "SELECT name, ?   FROM people"    # wrong (but may not 'fail')
419
420       Also, placeholders can only represent single scalar values.  For
421       example, the following statement won't work as expected for more than
422       one value:
423
424         "SELECT name, age FROM people WHERE name IN (?)"    # wrong
425         "SELECT name, age FROM people WHERE name IN (?,?)"  # two names
426
427       When using placeholders with the SQL "LIKE" qualifier, you must
428       remember that the placeholder substitutes for the whole string.  So you
429       should use ""... LIKE ? ..."" and include any wildcard characters in
430       the value that you bind to the placeholder.
431
432       NULL Values
433
434       Undefined values, or "undef", are used to indicate NULL values.  You
435       can insert and update columns with a NULL value as you would a non-NULL
436       value.  These examples insert and update the column "age" with a NULL
437       value:
438
439         $sth = $dbh->prepare(qq{
440           INSERT INTO people (fullname, age) VALUES (?, ?)
441         });
442         $sth->execute("Joe Bloggs", undef);
443
444         $sth = $dbh->prepare(qq{
445           UPDATE people SET age = ? WHERE fullname = ?
446         });
447         $sth->execute(undef, "Joe Bloggs");
448
449       However, care must be taken when trying to use NULL values in a "WHERE"
450       clause.  Consider:
451
452         SELECT fullname FROM people WHERE age = ?
453
454       Binding an "undef" (NULL) to the placeholder will not select rows which
455       have a NULL "age"!  At least for database engines that conform to the
456       SQL standard.  Refer to the SQL manual for your database engine or any
457       SQL book for the reasons for this.  To explicitly select NULLs you have
458       to say ""WHERE age IS NULL"".
459
460       A common issue is to have a code fragment handle a value that could be
461       either "defined" or "undef" (non-NULL or NULL) at runtime.  A simple
462       technique is to prepare the appropriate statement as needed, and
463       substitute the placeholder for non-NULL cases:
464
465         $sql_clause = defined $age? "age = ?" : "age IS NULL";
466         $sth = $dbh->prepare(qq{
467           SELECT fullname FROM people WHERE $sql_clause
468         });
469         $sth->execute(defined $age ? $age : ());
470
471       The following technique illustrates qualifying a "WHERE" clause with
472       several columns, whose associated values ("defined" or "undef") are in
473       a hash %h:
474
475         for my $col ("age", "phone", "email") {
476           if (defined $h{$col}) {
477             push @sql_qual, "$col = ?";
478             push @sql_bind, $h{$col};
479           }
480           else {
481             push @sql_qual, "$col IS NULL";
482           }
483         }
484         $sql_clause = join(" AND ", @sql_qual);
485         $sth = $dbh->prepare(qq{
486             SELECT fullname FROM people WHERE $sql_clause
487         });
488         $sth->execute(@sql_bind);
489
490       The techniques above call prepare for the SQL statement with each call
491       to execute.  Because calls to prepare() can be expensive, performance
492       can suffer when an application iterates many times over statements like
493       the above.
494
495       A better solution is a single "WHERE" clause that supports both NULL
496       and non-NULL comparisons.  Its SQL statement would need to be prepared
497       only once for all cases, thus improving performance.  Several examples
498       of "WHERE" clauses that support this are presented below.  But each
499       example lacks portability, robustness, or simplicity.  Whether an
500       example is supported on your database engine depends on what SQL
501       extensions it provides, and where it supports the "?"  placeholder in a
502       statement.
503
504         0)  age = ?
505         1)  NVL(age, xx) = NVL(?, xx)
506         2)  ISNULL(age, xx) = ISNULL(?, xx)
507         3)  DECODE(age, ?, 1, 0) = 1
508         4)  age = ? OR (age IS NULL AND ? IS NULL)
509         5)  age = ? OR (age IS NULL AND SP_ISNULL(?) = 1)
510         6)  age = ? OR (age IS NULL AND ? = 1)
511
512       Statements formed with the above "WHERE" clauses require execute
513       statements as follows.  The arguments are required, whether their
514       values are "defined" or "undef".
515
516         0,1,2,3)  $sth->execute($age);
517         4,5)      $sth->execute($age, $age);
518         6)        $sth->execute($age, defined($age) ? 0 : 1);
519
520       Example 0 should not work (as mentioned earlier), but may work on a few
521       database engines anyway (e.g. Sybase).  Example 0 is part of examples
522       4, 5, and 6, so if example 0 works, these other examples may work, even
523       if the engine does not properly support the right hand side of the "OR"
524       expression.
525
526       Examples 1 and 2 are not robust: they require that you provide a valid
527       column value xx (e.g. '~') which is not present in any row.  That means
528       you must have some notion of what data won't be stored in the column,
529       and expect clients to adhere to that.
530
531       Example 5 requires that you provide a stored procedure (SP_ISNULL in
532       this example) that acts as a function: it checks whether a value is
533       null, and returns 1 if it is, or 0 if not.
534
535       Example 6, the least simple, is probably the most portable, i.e., it
536       should work with most, if not all, database engines.
537
538       Here is a table that indicates which examples above are known to work
539       on various database engines:
540
541                          -----Examples------
542                          0  1  2  3  4  5  6
543                          -  -  -  -  -  -  -
544         Oracle 9         N  Y  N  Y  Y  ?  Y
545         Informix IDS 9   N  N  N  Y  N  Y  Y
546         MS SQL           N  N  Y  N  Y  ?  Y
547         Sybase           Y  N  N  N  N  N  Y
548         AnyData,DBM,CSV  Y  N  N  N  Y  Y* Y
549         SQLite 3.3       N  N  N  N  Y  N  N
550         MSAccess         N  N  N  N  Y  N  Y
551
552       * Works only because Example 0 works.
553
554       DBI provides a sample perl script that will test the examples above on
555       your database engine and tell you which ones work.  It is located in
556       the ex/ subdirectory of the DBI source distribution, or here:
557       <https://github.com/perl5-dbi/dbi/blob/master/ex/perl_dbi_nulls_test.pl>
558       Please use the script to help us fill-in and maintain this table.
559
560       Performance
561
562       Without using placeholders, the insert statement shown previously would
563       have to contain the literal values to be inserted and would have to be
564       re-prepared and re-executed for each row. With placeholders, the insert
565       statement only needs to be prepared once. The bind values for each row
566       can be given to the "execute" method each time it's called. By avoiding
567       the need to re-prepare the statement for each row, the application
568       typically runs many times faster. Here's an example:
569
570         my $sth = $dbh->prepare(q{
571           INSERT INTO sales (product_code, qty, price) VALUES (?, ?, ?)
572         }) or die $dbh->errstr;
573         while (<>) {
574             chomp;
575             my ($product_code, $qty, $price) = split /,/;
576             $sth->execute($product_code, $qty, $price) or die $dbh->errstr;
577         }
578         $dbh->commit or die $dbh->errstr;
579
580       See "execute" and "bind_param" for more details.
581
582       The "q{...}" style quoting used in this example avoids clashing with
583       quotes that may be used in the SQL statement. Use the double-quote like
584       "qq{...}" operator if you want to interpolate variables into the
585       string.  See "Quote and Quote-like Operators" in perlop for more
586       details.
587
588       See also the "bind_columns" method, which is used to associate Perl
589       variables with the output columns of a "SELECT" statement.
590

THE DBI PACKAGE AND CLASS

592       In this section, we cover the DBI class methods, utility functions, and
593       the dynamic attributes associated with generic DBI handles.
594
595   DBI Constants
596       Constants representing the values of the SQL standard types can be
597       imported individually by name, or all together by importing the special
598       ":sql_types" tag.
599
600       The names and values of all the defined SQL standard types can be
601       produced like this:
602
603         foreach (@{ $DBI::EXPORT_TAGS{sql_types} }) {
604           printf "%s=%d\n", $_, &{"DBI::$_"};
605         }
606
607       These constants are defined by SQL/CLI, ODBC or both.  "SQL_BIGINT" has
608       conflicting codes in SQL/CLI and ODBC, DBI uses the ODBC one.
609
610       See the "type_info", "type_info_all", and "bind_param" methods for
611       possible uses.
612
613       Note that just because the DBI defines a named constant for a given
614       data type doesn't mean that drivers will support that data type.
615
616   DBI Class Methods
617       The following methods are provided by the DBI class:
618
619       "parse_dsn"
620
621         ($scheme, $driver, $attr_string, $attr_hash, $driver_dsn) = DBI->parse_dsn($dsn)
622             or die "Can't parse DBI DSN '$dsn'";
623
624       Breaks apart a DBI Data Source Name (DSN) and returns the individual
625       parts. If $dsn doesn't contain a valid DSN then parse_dsn() returns an
626       empty list.
627
628       $scheme is the first part of the DSN and is currently always 'dbi'.
629       $driver is the driver name, possibly defaulted to $ENV{DBI_DRIVER}, and
630       may be undefined.  $attr_string is the contents of the optional
631       attribute string, which may be undefined.  If $attr_string is not empty
632       then $attr_hash is a reference to a hash containing the parsed
633       attribute names and values.  $driver_dsn is the last part of the DBI
634       DSN string. For example:
635
636         ($scheme, $driver, $attr_string, $attr_hash, $driver_dsn)
637             = DBI->parse_dsn("dbi:MyDriver(RaiseError=>1):db=test;port=42");
638         $scheme      = 'dbi';
639         $driver      = 'MyDriver';
640         $attr_string = 'RaiseError=>1';
641         $attr_hash   = { 'RaiseError' => '1' };
642         $driver_dsn  = 'db=test;port=42';
643
644       The parse_dsn() method was added in DBI 1.43.
645
646       "connect"
647
648         $dbh = DBI->connect($data_source, $username, $password)
649                   or die $DBI::errstr;
650         $dbh = DBI->connect($data_source, $username, $password, \%attr)
651                   or die $DBI::errstr;
652
653       Establishes a database connection, or session, to the requested
654       $data_source.  Returns a database handle object if the connection
655       succeeds. Use "$dbh->disconnect" to terminate the connection.
656
657       If the connect fails (see below), it returns "undef" and sets both
658       $DBI::err and $DBI::errstr. (It does not explicitly set $!.) You should
659       generally test the return status of "connect" and "print $DBI::errstr"
660       if it has failed.
661
662       Multiple simultaneous connections to multiple databases through
663       multiple drivers can be made via the DBI. Simply make one "connect"
664       call for each database and keep a copy of each returned database
665       handle.
666
667       The $data_source value must begin with ""dbi:"driver_name":"".  The
668       driver_name specifies the driver that will be used to make the
669       connection. (Letter case is significant.)
670
671       As a convenience, if the $data_source parameter is undefined or empty,
672       the DBI will substitute the value of the environment variable
673       "DBI_DSN".  If just the driver_name part is empty (i.e., the
674       $data_source prefix is ""dbi::""), the environment variable
675       "DBI_DRIVER" is used. If neither variable is set, then "connect" dies.
676
677       Examples of $data_source values are:
678
679         dbi:DriverName:database_name
680         dbi:DriverName:database_name@hostname:port
681         dbi:DriverName:database=database_name;host=hostname;port=port
682
683       There is no standard for the text following the driver name. Each
684       driver is free to use whatever syntax it wants. The only requirement
685       the DBI makes is that all the information is supplied in a single
686       string.  You must consult the documentation for the drivers you are
687       using for a description of the syntax they require.
688
689       It is recommended that drivers support the ODBC style, shown in the
690       last example above. It is also recommended that they support the three
691       common names '"host"', '"port"', and '"database"' (plus '"db"' as an
692       alias for "database"). This simplifies automatic construction of basic
693       DSNs: "dbi:$driver:database=$db;host=$host;port=$port".  Drivers should
694       aim to 'do something reasonable' when given a DSN in this form, but if
695       any part is meaningless for that driver (such as 'port' for Informix)
696       it should generate an error if that part is not empty.
697
698       If the environment variable "DBI_AUTOPROXY" is defined (and the driver
699       in $data_source is not ""Proxy"") then the connect request will
700       automatically be changed to:
701
702         $ENV{DBI_AUTOPROXY};dsn=$data_source
703
704       "DBI_AUTOPROXY" is typically set as
705       ""dbi:Proxy:hostname=...;port=..."".  If $ENV{DBI_AUTOPROXY} doesn't
706       begin with '"dbi:"' then "dbi:Proxy:" will be prepended to it first.
707       See the DBD::Proxy documentation for more details.
708
709       If $username or $password are undefined (rather than just empty), then
710       the DBI will substitute the values of the "DBI_USER" and "DBI_PASS"
711       environment variables, respectively.  The DBI will warn if the
712       environment variables are not defined.  However, the everyday use of
713       these environment variables is not recommended for security reasons.
714       The mechanism is primarily intended to simplify testing.  See below for
715       alternative way to specify the username and password.
716
717       "DBI->connect" automatically installs the driver if it has not been
718       installed yet. Driver installation either returns a valid driver
719       handle, or it dies with an error message that includes the string
720       ""install_driver"" and the underlying problem. So "DBI->connect" will
721       die on a driver installation failure and will only return "undef" on a
722       connect failure, in which case $DBI::errstr will hold the error
723       message.  Use "eval" if you need to catch the ""install_driver"" error.
724
725       The $data_source argument (with the ""dbi:...:"" prefix removed) and
726       the $username and $password arguments are then passed to the driver for
727       processing. The DBI does not define any interpretation for the contents
728       of these fields.  The driver is free to interpret the $data_source,
729       $username, and $password fields in any way, and supply whatever
730       defaults are appropriate for the engine being accessed.  (Oracle, for
731       example, uses the ORACLE_SID and TWO_TASK environment variables if no
732       $data_source is specified.)
733
734       The "AutoCommit" and "PrintError" attributes for each connection
735       default to "on". (See "AutoCommit" and "PrintError" for more
736       information.)  However, it is strongly recommended that you explicitly
737       define "AutoCommit" rather than rely on the default. The "PrintWarn"
738       attribute defaults to true.
739
740       The "\%attr" parameter can be used to alter the default settings of
741       "PrintError", "RaiseError", "AutoCommit", and other attributes. For
742       example:
743
744         $dbh = DBI->connect($data_source, $user, $pass, {
745               PrintError => 0,
746               AutoCommit => 0
747         });
748
749       The username and password can also be specified using the attributes
750       "Username" and "Password", in which case they take precedence over the
751       $username and $password parameters.
752
753       You can also define connection attribute values within the $data_source
754       parameter. For example:
755
756         dbi:DriverName(PrintWarn=>0,PrintError=>0,Taint=>1):...
757
758       Individual attributes values specified in this way take precedence over
759       any conflicting values specified via the "\%attr" parameter to
760       "connect".
761
762       The "dbi_connect_method" attribute can be used to specify which driver
763       method should be called to establish the connection. The only useful
764       values are 'connect', 'connect_cached', or some specialized case like
765       'Apache::DBI::connect' (which is automatically the default when running
766       within Apache).
767
768       Where possible, each session ($dbh) is independent from the
769       transactions in other sessions. This is useful when you need to hold
770       cursors open across transactions--for example, if you use one session
771       for your long lifespan cursors (typically read-only) and another for
772       your short update transactions.
773
774       For compatibility with old DBI scripts, the driver can be specified by
775       passing its name as the fourth argument to "connect" (instead of
776       "\%attr"):
777
778         $dbh = DBI->connect($data_source, $user, $pass, $driver);
779
780       In this "old-style" form of "connect", the $data_source should not
781       start with ""dbi:driver_name:"". (If it does, the embedded driver_name
782       will be ignored). Also note that in this older form of "connect", the
783       "$dbh->{AutoCommit}" attribute is undefined, the "$dbh->{PrintError}"
784       attribute is off, and the old "DBI_DBNAME" environment variable is
785       checked if "DBI_DSN" is not defined. Beware that this "old-style"
786       "connect" will soon be withdrawn in a future version of DBI.
787
788       "connect_cached"
789
790         $dbh = DBI->connect_cached($data_source, $username, $password)
791                   or die $DBI::errstr;
792         $dbh = DBI->connect_cached($data_source, $username, $password, \%attr)
793                   or die $DBI::errstr;
794
795       "connect_cached" is like "connect", except that the database handle
796       returned is also stored in a hash associated with the given parameters.
797       If another call is made to "connect_cached" with the same parameter
798       values, then the corresponding cached $dbh will be returned if it is
799       still valid.  The cached database handle is replaced with a new
800       connection if it has been disconnected or if the "ping" method fails.
801
802       Note that the behaviour of this method differs in several respects from
803       the behaviour of persistent connections implemented by Apache::DBI.
804       However, if Apache::DBI is loaded then "connect_cached" will use it.
805
806       Caching connections can be useful in some applications, but it can also
807       cause problems, such as too many connections, and so should be used
808       with care. In particular, avoid changing the attributes of a database
809       handle created via connect_cached() because it will affect other code
810       that may be using the same handle. When connect_cached() returns a
811       handle the attributes will be reset to their initial values.  This can
812       cause problems, especially with the "AutoCommit" attribute.
813
814       Also, to ensure that the attributes passed are always the same, avoid
815       passing references inline. For example, the "Callbacks" attribute is
816       specified as a hash reference. Be sure to declare it external to the
817       call to connect_cached(), such that the hash reference is not re-
818       created on every call. A package-level lexical works well:
819
820         package MyDBH;
821         my $cb = {
822             'connect_cached.reused' => sub { delete $_[4]->{AutoCommit} },
823         };
824
825         sub dbh {
826             DBI->connect_cached( $dsn, $username, $auth, { Callbacks => $cb });
827         }
828
829       Where multiple separate parts of a program are using connect_cached()
830       to connect to the same database with the same (initial) attributes it
831       is a good idea to add a private attribute to the connect_cached() call
832       to effectively limit the scope of the caching. For example:
833
834         DBI->connect_cached(..., { private_foo_cachekey => "Bar", ... });
835
836       Handles returned from that connect_cached() call will only be returned
837       by other connect_cached() call elsewhere in the code if those other
838       calls also pass in the same attribute values, including the private
839       one.  (I've used "private_foo_cachekey" here as an example, you can use
840       any attribute name with a "private_" prefix.)
841
842       Taking that one step further, you can limit a particular
843       connect_cached() call to return handles unique to that one place in the
844       code by setting the private attribute to a unique value for that place:
845
846         DBI->connect_cached(..., { private_foo_cachekey => __FILE__.__LINE__, ... });
847
848       By using a private attribute you still get connection caching for the
849       individual calls to connect_cached() but, by making separate database
850       connections for separate parts of the code, the database handles are
851       isolated from any attribute changes made to other handles.
852
853       The cache can be accessed (and cleared) via the "CachedKids" attribute:
854
855         my $CachedKids_hashref = $dbh->{Driver}->{CachedKids};
856         %$CachedKids_hashref = () if $CachedKids_hashref;
857
858       "available_drivers"
859
860         @ary = DBI->available_drivers;
861         @ary = DBI->available_drivers($quiet);
862
863       Returns a list of all available drivers by searching for "DBD::*"
864       modules through the directories in @INC. By default, a warning is given
865       if some drivers are hidden by others of the same name in earlier
866       directories. Passing a true value for $quiet will inhibit the warning.
867
868       "installed_drivers"
869
870         %drivers = DBI->installed_drivers();
871
872       Returns a list of driver name and driver handle pairs for all drivers
873       'installed' (loaded) into the current process.  The driver name does
874       not include the 'DBD::' prefix.
875
876       To get a list of all drivers available in your perl installation you
877       can use "available_drivers".
878
879       Added in DBI 1.49.
880
881       "installed_versions"
882
883         DBI->installed_versions;
884         @ary  = DBI->installed_versions;
885         $hash = DBI->installed_versions;
886
887       Calls available_drivers() and attempts to load each of them in turn
888       using install_driver().  For each load that succeeds the driver name
889       and version number are added to a hash. When running under
890       DBI::PurePerl drivers which appear not be pure-perl are ignored.
891
892       When called in array context the list of successfully loaded drivers is
893       returned (without the 'DBD::' prefix).
894
895       When called in scalar context an extra entry for the "DBI" is added
896       (and "DBI::PurePerl" if appropriate) and a reference to the hash is
897       returned.
898
899       When called in a void context the installed_versions() method will
900       print out a formatted list of the hash contents, one per line, along
901       with some other information about the DBI version and OS.
902
903       Due to the potentially high memory cost and unknown risks of loading in
904       an unknown number of drivers that just happen to be installed on the
905       system, this method is not recommended for general use.  Use
906       available_drivers() instead.
907
908       The installed_versions() method is primarily intended as a quick way to
909       see from the command line what's installed. For example:
910
911         perl -MDBI -e 'DBI->installed_versions'
912
913       The installed_versions() method was added in DBI 1.38.
914
915       "data_sources"
916
917         @ary = DBI->data_sources($driver);
918         @ary = DBI->data_sources($driver, \%attr);
919
920       Returns a list of data sources (databases) available via the named
921       driver.  If $driver is empty or "undef", then the value of the
922       "DBI_DRIVER" environment variable is used.
923
924       The driver will be loaded if it hasn't been already. Note that if the
925       driver loading fails then data_sources() dies with an error message
926       that includes the string ""install_driver"" and the underlying problem.
927
928       Data sources are returned in a form suitable for passing to the
929       "connect" method (that is, they will include the ""dbi:$driver:""
930       prefix).
931
932       Note that many drivers have no way of knowing what data sources might
933       be available for it. These drivers return an empty or incomplete list
934       or may require driver-specific attributes.
935
936       There is also a data_sources() method defined for database handles.
937
938       "trace"
939
940         DBI->trace($trace_setting)
941         DBI->trace($trace_setting, $trace_filename)
942         DBI->trace($trace_setting, $trace_filehandle)
943         $trace_setting = DBI->trace;
944
945       The "DBI->trace" method sets the global default trace settings and
946       returns the previous trace settings. It can also be used to change
947       where the trace output is sent.
948
949       There's a similar method, "$h->trace", which sets the trace settings
950       for the specific handle it's called on.
951
952       See the "TRACING" section for full details about the DBI's powerful
953       tracing facilities.
954
955       "visit_handles"
956
957         DBI->visit_handles( $coderef );
958         DBI->visit_handles( $coderef, $info );
959
960       Where $coderef is a reference to a subroutine and $info is an arbitrary
961       value which, if undefined, defaults to a reference to an empty hash.
962       Returns $info.
963
964       For each installed driver handle, if any, $coderef is invoked as:
965
966         $coderef->($driver_handle, $info);
967
968       If the execution of $coderef returns a true value then
969       "visit_child_handles" is called on that child handle and passed the
970       returned value as $info.
971
972       For example:
973
974         my $info = $dbh->{Driver}->visit_child_handles(sub {
975             my ($h, $info) = @_;
976             ++$info->{ $h->{Type} }; # count types of handles (dr/db/st)
977             return $info; # visit kids
978         });
979
980       See also "visit_child_handles".
981
982   DBI Utility Functions
983       In addition to the DBI methods listed in the previous section, the DBI
984       package also provides several utility functions.
985
986       These can be imported into your code by listing them in the "use"
987       statement. For example:
988
989         use DBI qw(neat data_diff);
990
991       Alternatively, all these utility functions (except hash) can be
992       imported using the ":utils" import tag. For example:
993
994         use DBI qw(:utils);
995
996       "data_string_desc"
997
998         $description = data_string_desc($string);
999
1000       Returns an informal description of the string. For example:
1001
1002         UTF8 off, ASCII, 42 characters 42 bytes
1003         UTF8 off, non-ASCII, 42 characters 42 bytes
1004         UTF8 on, non-ASCII, 4 characters 6 bytes
1005         UTF8 on but INVALID encoding, non-ASCII, 4 characters 6 bytes
1006         UTF8 off, undef
1007
1008       The initial "UTF8" on/off refers to Perl's internal SvUTF8 flag.  If
1009       $string has the SvUTF8 flag set but the sequence of bytes it contains
1010       are not a valid UTF-8 encoding then data_string_desc() will report
1011       "UTF8 on but INVALID encoding".
1012
1013       The "ASCII" vs "non-ASCII" portion shows "ASCII" if all the characters
1014       in the string are ASCII (have code points <= 127).
1015
1016       The data_string_desc() function was added in DBI 1.46.
1017
1018       "data_string_diff"
1019
1020         $diff = data_string_diff($a, $b);
1021
1022       Returns an informal description of the first character difference
1023       between the strings. If both $a and $b contain the same sequence of
1024       characters then data_string_diff() returns an empty string.  For
1025       example:
1026
1027        Params a & b     Result
1028        ------------     ------
1029        'aaa', 'aaa'     ''
1030        'aaa', 'abc'     'Strings differ at index 2: a[2]=a, b[2]=b'
1031        'aaa', undef     'String b is undef, string a has 3 characters'
1032        'aaa', 'aa'      'String b truncated after 2 characters'
1033
1034       Unicode characters are reported in "\x{XXXX}" format. Unicode code
1035       points in the range U+0800 to U+08FF are unassigned and most likely to
1036       occur due to double-encoding. Characters in this range are reported as
1037       "\x{08XX}='C'" where "C" is the corresponding latin-1 character.
1038
1039       The data_string_diff() function only considers logical characters and
1040       not the underlying encoding. See "data_diff" for an alternative.
1041
1042       The data_string_diff() function was added in DBI 1.46.
1043
1044       "data_diff"
1045
1046         $diff = data_diff($a, $b);
1047         $diff = data_diff($a, $b, $logical);
1048
1049       Returns an informal description of the difference between two strings.
1050       It calls "data_string_desc" and "data_string_diff" and returns the
1051       combined results as a multi-line string.
1052
1053       For example, "data_diff("abc", "ab\x{263a}")" will return:
1054
1055         a: UTF8 off, ASCII, 3 characters 3 bytes
1056         b: UTF8 on, non-ASCII, 3 characters 5 bytes
1057         Strings differ at index 2: a[2]=c, b[2]=\x{263A}
1058
1059       If $a and $b are identical in both the characters they contain and
1060       their physical encoding then data_diff() returns an empty string.  If
1061       $logical is true then physical encoding differences are ignored (but
1062       are still reported if there is a difference in the characters).
1063
1064       The data_diff() function was added in DBI 1.46.
1065
1066       "neat"
1067
1068         $str = neat($value);
1069         $str = neat($value, $maxlen);
1070
1071       Return a string containing a neat (and tidy) representation of the
1072       supplied value.
1073
1074       Strings will be quoted, although internal quotes will not be escaped.
1075       Values known to be numeric will be unquoted. Undefined (NULL) values
1076       will be shown as "undef" (without quotes).
1077
1078       If the string is flagged internally as utf8 then double quotes will be
1079       used, otherwise single quotes are used and unprintable characters will
1080       be replaced by dot (.).
1081
1082       For result strings longer than $maxlen the result string will be
1083       truncated to "$maxlen-4" and ""...'"" will be appended.  If $maxlen is
1084       0 or "undef", it defaults to $DBI::neat_maxlen which, in turn, defaults
1085       to 400.
1086
1087       This function is designed to format values for human consumption.  It
1088       is used internally by the DBI for "trace" output. It should typically
1089       not be used for formatting values for database use.  (See also
1090       "quote".)
1091
1092       "neat_list"
1093
1094         $str = neat_list(\@listref, $maxlen, $field_sep);
1095
1096       Calls "neat" on each element of the list and returns a string
1097       containing the results joined with $field_sep. $field_sep defaults to
1098       ", ".
1099
1100       "looks_like_number"
1101
1102         @bool = looks_like_number(@array);
1103
1104       Returns true for each element that looks like a number.  Returns false
1105       for each element that does not look like a number.  Returns "undef" for
1106       each element that is undefined or empty.
1107
1108       "hash"
1109
1110         $hash_value = DBI::hash($buffer, $type);
1111
1112       Return a 32-bit integer 'hash' value corresponding to the contents of
1113       $buffer.  The $type parameter selects which kind of hash algorithm
1114       should be used.
1115
1116       For the technically curious, type 0 (which is the default if $type
1117       isn't specified) is based on the Perl 5.1 hash except that the value is
1118       forced to be negative (for obscure historical reasons).  Type 1 is the
1119       better "Fowler / Noll / Vo" (FNV) hash. See
1120       <http://www.isthe.com/chongo/tech/comp/fnv/> for more information.
1121       Both types are implemented in C and are very fast.
1122
1123       This function doesn't have much to do with databases, except that it
1124       can sometimes be handy to store such values in a database.  It also
1125       doesn't have much to do with perl hashes, like %foo.
1126
1127       "sql_type_cast"
1128
1129         $sts = DBI::sql_type_cast($sv, $sql_type, $flags);
1130
1131       sql_type_cast attempts to cast $sv to the SQL type (see DBI Constants)
1132       specified in $sql_type. At present only the SQL types "SQL_INTEGER",
1133       "SQL_DOUBLE" and "SQL_NUMERIC" are supported.
1134
1135       For "SQL_INTEGER" the effect is similar to using the value in an
1136       expression that requires an integer. It gives the perl scalar an
1137       'integer aspect'.  (Technically the value gains an IV, or possibly a UV
1138       or NV if the value is too large for an IV.)
1139
1140       For "SQL_DOUBLE" the effect is similar to using the value in an
1141       expression that requires a general numeric value. It gives the perl
1142       scalar a 'numeric aspect'.  (Technically the value gains an NV.)
1143
1144       "SQL_NUMERIC" is similar to "SQL_INTEGER" or "SQL_DOUBLE" but more
1145       general and more cautious.  It will look at the string first and if it
1146       looks like an integer (that will fit in an IV or UV) it will act like
1147       "SQL_INTEGER", if it looks like a floating point value it will act like
1148       "SQL_DOUBLE", if it looks like neither then it will do nothing - and
1149       thereby avoid the warnings that would be generated by "SQL_INTEGER" and
1150       "SQL_DOUBLE" when given non-numeric data.
1151
1152       $flags may be:
1153
1154       "DBIstcf_DISCARD_STRING"
1155           If this flag is specified then when the driver successfully casts
1156           the bound perl scalar to a non-string type then the string portion
1157           of the scalar will be discarded.
1158
1159       "DBIstcf_STRICT"
1160           If $sv cannot be cast to the requested $sql_type then by default it
1161           is left untouched and no error is generated. If you specify
1162           "DBIstcf_STRICT" and the cast fails, this will generate an error.
1163
1164       The returned $sts value is:
1165
1166         -2 sql_type is not handled
1167         -1 sv is undef so unchanged
1168          0 sv could not be cast cleanly and DBIstcf_STRICT was used
1169          1 sv could not be cast and DBIstcf_STRICT was not used
1170          2 sv was cast successfully
1171
1172       This method is exported by the :utils tag and was introduced in DBI
1173       1.611.
1174
1175   DBI Dynamic Attributes
1176       Dynamic attributes are always associated with the last handle used
1177       (that handle is represented by $h in the descriptions below).
1178
1179       Where an attribute is equivalent to a method call, then refer to the
1180       method call for all related documentation.
1181
1182       Warning: these attributes are provided as a convenience but they do
1183       have limitations. Specifically, they have a short lifespan: because
1184       they are associated with the last handle used, they should only be used
1185       immediately after calling the method that "sets" them.  If in any
1186       doubt, use the corresponding method call.
1187
1188       $DBI::err
1189
1190       Equivalent to "$h->err".
1191
1192       $DBI::errstr
1193
1194       Equivalent to "$h->errstr".
1195
1196       $DBI::state
1197
1198       Equivalent to "$h->state".
1199
1200       $DBI::rows
1201
1202       Equivalent to "$h->rows". Please refer to the documentation for the
1203       "rows" method.
1204
1205       $DBI::lasth
1206
1207       Returns the DBI object handle used for the most recent DBI method call.
1208       If the last DBI method call was a DESTROY then $DBI::lasth will return
1209       the handle of the parent of the destroyed handle, if there is one.
1210

METHODS COMMON TO ALL HANDLES

1212       The following methods can be used by all types of DBI handles.
1213
1214       "err"
1215
1216         $rv = $h->err;
1217
1218       Returns the native database engine error code from the last driver
1219       method called. The code is typically an integer but you should not
1220       assume that.
1221
1222       The DBI resets $h->err to undef before almost all DBI method calls, so
1223       the value only has a short lifespan. Also, for most drivers, the
1224       statement handles share the same error variable as the parent database
1225       handle, so calling a method on one handle may reset the error on the
1226       related handles.
1227
1228       (Methods which don't reset err before being called include err() and
1229       errstr(), obviously, state(), rows(), func(), trace(), trace_msg(),
1230       ping(), and the tied hash attribute FETCH() and STORE() methods.)
1231
1232       If you need to test for specific error conditions and have your program
1233       be portable to different database engines, then you'll need to
1234       determine what the corresponding error codes are for all those engines
1235       and test for all of them.
1236
1237       The DBI uses the value of $DBI::stderr as the "err" value for internal
1238       errors.  Drivers should also do likewise.  The default value for
1239       $DBI::stderr is 2000000000.
1240
1241       A driver may return 0 from err() to indicate a warning condition after
1242       a method call. Similarly, a driver may return an empty string to
1243       indicate a 'success with information' condition. In both these cases
1244       the value is false but not undef. The errstr() and state() methods may
1245       be used to retrieve extra information in these cases.
1246
1247       See "set_err" for more information.
1248
1249       "errstr"
1250
1251         $str = $h->errstr;
1252
1253       Returns the native database engine error message from the last DBI
1254       method called. This has the same lifespan issues as the "err" method
1255       described above.
1256
1257       The returned string may contain multiple messages separated by newline
1258       characters.
1259
1260       The errstr() method should not be used to test for errors, use err()
1261       for that, because drivers may return 'success with information' or
1262       warning messages via errstr() for methods that have not 'failed'.
1263
1264       See "set_err" for more information.
1265
1266       "state"
1267
1268         $str = $h->state;
1269
1270       Returns a state code in the standard SQLSTATE five character format.
1271       Note that the specific success code 00000 is translated to any empty
1272       string (false). If the driver does not support SQLSTATE (and most
1273       don't), then state() will return "S1000" (General Error) for all
1274       errors.
1275
1276       The driver is free to return any value via "state", e.g., warning
1277       codes, even if it has not declared an error by returning a true value
1278       via the "err" method described above.
1279
1280       The state() method should not be used to test for errors, use err() for
1281       that, because drivers may return a 'success with information' or
1282       warning state code via state() for methods that have not 'failed'.
1283
1284       "set_err"
1285
1286         $rv = $h->set_err($err, $errstr);
1287         $rv = $h->set_err($err, $errstr, $state);
1288         $rv = $h->set_err($err, $errstr, $state, $method);
1289         $rv = $h->set_err($err, $errstr, $state, $method, $rv);
1290
1291       Set the "err", "errstr", and "state" values for the handle.  This
1292       method is typically only used by DBI drivers and DBI subclasses.
1293
1294       If the "HandleSetErr" attribute holds a reference to a subroutine it is
1295       called first. The subroutine can alter the $err, $errstr, $state, and
1296       $method values. See "HandleSetErr" for full details.  If the subroutine
1297       returns a true value then the handle "err", "errstr", and "state"
1298       values are not altered and set_err() returns an empty list (it normally
1299       returns $rv which defaults to undef, see below).
1300
1301       Setting "err" to a true value indicates an error and will trigger the
1302       normal DBI error handling mechanisms, such as "RaiseError" and
1303       "HandleError", if they are enabled, when execution returns from the DBI
1304       back to the application.
1305
1306       Setting "err" to "" indicates an 'information' state, and setting it to
1307       "0" indicates a 'warning' state. Setting "err" to "undef" also sets
1308       "errstr" to undef, and "state" to "", irrespective of the values of the
1309       $errstr and $state parameters.
1310
1311       The $method parameter provides an alternate method name for the
1312       "RaiseError"/"PrintError"/"PrintWarn" error string instead of the
1313       fairly unhelpful '"set_err"'.
1314
1315       The "set_err" method normally returns undef.  The $rv parameter
1316       provides an alternate return value.
1317
1318       Some special rules apply if the "err" or "errstr" values for the handle
1319       are already set...
1320
1321       If "errstr" is true then: "" [err was %s now %s]"" is appended if $err
1322       is true and "err" is already true and the new err value differs from
1323       the original one. Similarly "" [state was %s now %s]"" is appended if
1324       $state is true and "state" is already true and the new state value
1325       differs from the original one. Finally ""\n"" and the new $errstr are
1326       appended if $errstr differs from the existing errstr value. Obviously
1327       the %s's above are replaced by the corresponding values.
1328
1329       The handle "err" value is set to $err if: $err is true; or handle "err"
1330       value is undef; or $err is defined and the length is greater than the
1331       handle "err" length. The effect is that an 'information' state only
1332       overrides undef; a 'warning' overrides undef or 'information', and an
1333       'error' state overrides anything.
1334
1335       The handle "state" value is set to $state if $state is true and the
1336       handle "err" value was set (by the rules above).
1337
1338       Support for warning and information states was added in DBI 1.41.
1339
1340       "trace"
1341
1342         $h->trace($trace_settings);
1343         $h->trace($trace_settings, $trace_filename);
1344         $trace_settings = $h->trace;
1345
1346       The trace() method is used to alter the trace settings for a handle
1347       (and any future children of that handle).  It can also be used to
1348       change where the trace output is sent.
1349
1350       There's a similar method, "DBI->trace", which sets the global default
1351       trace settings.
1352
1353       See the "TRACING" section for full details about the DBI's powerful
1354       tracing facilities.
1355
1356       "trace_msg"
1357
1358         $h->trace_msg($message_text);
1359         $h->trace_msg($message_text, $min_level);
1360
1361       Writes $message_text to the trace file if the trace level is greater
1362       than or equal to $min_level (which defaults to 1).  Can also be called
1363       as "DBI->trace_msg($msg)".
1364
1365       See "TRACING" for more details.
1366
1367       "func"
1368
1369         $h->func(@func_arguments, $func_name) or die ...;
1370
1371       The "func" method can be used to call private non-standard and non-
1372       portable methods implemented by the driver. Note that the function name
1373       is given as the last argument.
1374
1375       It's also important to note that the func() method does not clear a
1376       previous error ($DBI::err etc.) and it does not trigger automatic error
1377       detection (RaiseError etc.) so you must check the return status and/or
1378       $h->err to detect errors.
1379
1380       (This method is not directly related to calling stored procedures.
1381       Calling stored procedures is currently not defined by the DBI.  Some
1382       drivers, such as DBD::Oracle, support it in non-portable ways.  See
1383       driver documentation for more details.)
1384
1385       See also install_method() in DBI::DBD for how you can avoid needing to
1386       use func() and gain direct access to driver-private methods.
1387
1388       "can"
1389
1390         $is_implemented = $h->can($method_name);
1391
1392       Returns true if $method_name is implemented by the driver or a default
1393       method is provided by the DBI's driver base class.  It returns false
1394       where a driver hasn't implemented a method and the default method is
1395       provided by the DBI's driver base class is just an empty stub.
1396
1397       "parse_trace_flags"
1398
1399         $trace_settings_integer = $h->parse_trace_flags($trace_settings);
1400
1401       Parses a string containing trace settings and returns the corresponding
1402       integer value used internally by the DBI and drivers.
1403
1404       The $trace_settings argument is a string containing a trace level
1405       between 0 and 15 and/or trace flag names separated by vertical bar
1406       (""|"") or comma ("","") characters. For example: "SQL|3|foo".
1407
1408       It uses the parse_trace_flag() method, described below, to process the
1409       individual trace flag names.
1410
1411       The parse_trace_flags() method was added in DBI 1.42.
1412
1413       "parse_trace_flag"
1414
1415         $bit_flag = $h->parse_trace_flag($trace_flag_name);
1416
1417       Returns the bit flag corresponding to the trace flag name in
1418       $trace_flag_name.  Drivers are expected to override this method and
1419       check if $trace_flag_name is a driver specific trace flags and, if not,
1420       then call the DBI's default parse_trace_flag().
1421
1422       The parse_trace_flag() method was added in DBI 1.42.
1423
1424       "private_attribute_info"
1425
1426         $hash_ref = $h->private_attribute_info();
1427
1428       Returns a reference to a hash whose keys are the names of driver-
1429       private handle attributes available for the kind of handle (driver,
1430       database, statement) that the method was called on.
1431
1432       For example, the return value when called with a DBD::Sybase $dbh could
1433       look like this:
1434
1435         {
1436             syb_dynamic_supported => undef,
1437             syb_oc_version => undef,
1438             syb_server_version => undef,
1439             syb_server_version_string => undef,
1440         }
1441
1442       and when called with a DBD::Sybase $sth they could look like this:
1443
1444         {
1445             syb_types => undef,
1446             syb_proc_status => undef,
1447             syb_result_type => undef,
1448         }
1449
1450       The values should be undef. Meanings may be assigned to particular
1451       values in future.
1452
1453       "swap_inner_handle"
1454
1455         $rc = $h1->swap_inner_handle( $h2 );
1456         $rc = $h1->swap_inner_handle( $h2, $allow_reparent );
1457
1458       Brain transplants for handles. You don't need to know about this unless
1459       you want to become a handle surgeon.
1460
1461       A DBI handle is a reference to a tied hash. A tied hash has an inner
1462       hash that actually holds the contents.  The swap_inner_handle() method
1463       swaps the inner hashes between two handles. The $h1 and $h2 handles
1464       still point to the same tied hashes, but what those hashes are tied to
1465       has been swapped.  In effect $h1 becomes $h2 and vice-versa. This is
1466       powerful stuff, expect problems. Use with care.
1467
1468       As a small safety measure, the two handles, $h1 and $h2, have to share
1469       the same parent unless $allow_reparent is true.
1470
1471       The swap_inner_handle() method was added in DBI 1.44.
1472
1473       Here's a quick kind of 'diagram' as a worked example to help think
1474       about what's happening:
1475
1476           Original state:
1477                   dbh1o -> dbh1i
1478                   sthAo -> sthAi(dbh1i)
1479                   dbh2o -> dbh2i
1480
1481           swap_inner_handle dbh1o with dbh2o:
1482                   dbh2o -> dbh1i
1483                   sthAo -> sthAi(dbh1i)
1484                   dbh1o -> dbh2i
1485
1486           create new sth from dbh1o:
1487                   dbh2o -> dbh1i
1488                   sthAo -> sthAi(dbh1i)
1489                   dbh1o -> dbh2i
1490                   sthBo -> sthBi(dbh2i)
1491
1492           swap_inner_handle sthAo with sthBo:
1493                   dbh2o -> dbh1i
1494                   sthBo -> sthAi(dbh1i)
1495                   dbh1o -> dbh2i
1496                   sthAo -> sthBi(dbh2i)
1497
1498       "visit_child_handles"
1499
1500         $h->visit_child_handles( $coderef );
1501         $h->visit_child_handles( $coderef, $info );
1502
1503       Where $coderef is a reference to a subroutine and $info is an arbitrary
1504       value which, if undefined, defaults to a reference to an empty hash.
1505       Returns $info.
1506
1507       For each child handle of $h, if any, $coderef is invoked as:
1508
1509         $coderef->($child_handle, $info);
1510
1511       If the execution of $coderef returns a true value then
1512       "visit_child_handles" is called on that child handle and passed the
1513       returned value as $info.
1514
1515       For example:
1516
1517         # count database connections with names (DSN) matching a pattern
1518         my $connections = 0;
1519         $dbh->{Driver}->visit_child_handles(sub {
1520             my ($h, $info) = @_;
1521             ++$connections if $h->{Name} =~ /foo/;
1522             return 0; # don't visit kids
1523         })
1524
1525       See also "visit_handles".
1526

ATTRIBUTES COMMON TO ALL HANDLES

1528       These attributes are common to all types of DBI handles.
1529
1530       Some attributes are inherited by child handles. That is, the value of
1531       an inherited attribute in a newly created statement handle is the same
1532       as the value in the parent database handle. Changes to attributes in
1533       the new statement handle do not affect the parent database handle and
1534       changes to the database handle do not affect existing statement
1535       handles, only future ones.
1536
1537       Attempting to set or get the value of an unknown attribute generates a
1538       warning, except for private driver specific attributes (which all have
1539       names starting with a lowercase letter).
1540
1541       Example:
1542
1543         $h->{AttributeName} = ...;    # set/write
1544         ... = $h->{AttributeName};    # get/read
1545
1546       "Warn"
1547
1548       Type: boolean, inherited
1549
1550       The "Warn" attribute enables useful warnings for certain bad practices.
1551       It is enabled by default and should only be disabled in rare
1552       circumstances.  Since warnings are generated using the Perl "warn"
1553       function, they can be intercepted using the Perl $SIG{__WARN__} hook.
1554
1555       The "Warn" attribute is not related to the "PrintWarn" attribute.
1556
1557       "Active"
1558
1559       Type: boolean, read-only
1560
1561       The "Active" attribute is true if the handle object is "active". This
1562       is rarely used in applications. The exact meaning of active is somewhat
1563       vague at the moment. For a database handle it typically means that the
1564       handle is connected to a database ("$dbh->disconnect" sets "Active"
1565       off).  For a statement handle it typically means that the handle is a
1566       "SELECT" that may have more data to fetch. (Fetching all the data or
1567       calling "$sth->finish" sets "Active" off.)
1568
1569       "Executed"
1570
1571       Type: boolean
1572
1573       The "Executed" attribute is true if the handle object has been
1574       "executed".  Currently only the $dbh do() method and the $sth
1575       execute(), execute_array(), and execute_for_fetch() methods set the
1576       "Executed" attribute.
1577
1578       When it's set on a handle it is also set on the parent handle at the
1579       same time. So calling execute() on a $sth also sets the "Executed"
1580       attribute on the parent $dbh.
1581
1582       The "Executed" attribute for a database handle is cleared by the
1583       commit() and rollback() methods (even if they fail). The "Executed"
1584       attribute of a statement handle is not cleared by the DBI under any
1585       circumstances and so acts as a permanent record of whether the
1586       statement handle was ever used.
1587
1588       The "Executed" attribute was added in DBI 1.41.
1589
1590       "Kids"
1591
1592       Type: integer, read-only
1593
1594       For a driver handle, "Kids" is the number of currently existing
1595       database handles that were created from that driver handle.  For a
1596       database handle, "Kids" is the number of currently existing statement
1597       handles that were created from that database handle.  For a statement
1598       handle, the value is zero.
1599
1600       "ActiveKids"
1601
1602       Type: integer, read-only
1603
1604       Like "Kids", but only counting those that are "Active" (as above).
1605
1606       "CachedKids"
1607
1608       Type: hash ref
1609
1610       For a database handle, "CachedKids" returns a reference to the cache
1611       (hash) of statement handles created by the "prepare_cached" method.
1612       For a driver handle, returns a reference to the cache (hash) of
1613       database handles created by the "connect_cached" method.
1614
1615       "Type"
1616
1617       Type: scalar, read-only
1618
1619       The "Type" attribute identifies the type of a DBI handle.  Returns "dr"
1620       for driver handles, "db" for database handles and "st" for statement
1621       handles.
1622
1623       "ChildHandles"
1624
1625       Type: array ref
1626
1627       The ChildHandles attribute contains a reference to an array of all the
1628       handles created by this handle which are still accessible.  The
1629       contents of the array are weak-refs and will become undef when the
1630       handle goes out of scope. (They're cleared out occasionally.)
1631
1632       "ChildHandles" returns undef if your perl version does not support weak
1633       references (check the Scalar::Util module).  The referenced array
1634       returned should be treated as read-only.
1635
1636       For example, to enumerate all driver handles, database handles and
1637       statement handles:
1638
1639           sub show_child_handles {
1640               my ($h, $level) = @_;
1641               printf "%sh %s %s\n", $h->{Type}, "\t" x $level, $h;
1642               show_child_handles($_, $level + 1)
1643                   for (grep { defined } @{$h->{ChildHandles}});
1644           }
1645
1646           my %drivers = DBI->installed_drivers();
1647           show_child_handles($_, 0) for (values %drivers);
1648
1649       "CompatMode"
1650
1651       Type: boolean, inherited
1652
1653       The "CompatMode" attribute is used by emulation layers (such as
1654       Oraperl) to enable compatible behaviour in the underlying driver (e.g.,
1655       DBD::Oracle) for this handle. Not normally set by application code.
1656
1657       It also has the effect of disabling the 'quick FETCH' of attribute
1658       values from the handles attribute cache. So all attribute values are
1659       handled by the drivers own FETCH method. This makes them slightly
1660       slower but is useful for special-purpose drivers like DBD::Multiplex.
1661
1662       "InactiveDestroy"
1663
1664       Type: boolean
1665
1666       The default value, false, means a handle will be fully destroyed as
1667       normal when the last reference to it is removed, just as you'd expect.
1668
1669       If set true then the handle will be treated by the DESTROY as if it was
1670       no longer Active, and so the database engine related effects of
1671       DESTROYing a handle will be skipped.  Think of the name as meaning
1672       'treat the handle as not-Active in the DESTROY method'.
1673
1674       For a database handle, this attribute does not disable an explicit call
1675       to the disconnect method, only the implicit call from DESTROY that
1676       happens if the handle is still marked as "Active".
1677
1678       This attribute is specifically designed for use in Unix applications
1679       that "fork" child processes.  For some drivers, when the child process
1680       exits the destruction of inherited handles cause the corresponding
1681       handles in the parent process to cease working.
1682
1683       Either the parent or the child process, but not both, should set
1684       "InactiveDestroy" true on all their shared handles. Alternatively, and
1685       preferably, the "AutoInactiveDestroy" can be set in the parent on
1686       connect.
1687
1688       To help tracing applications using fork the process id is shown in the
1689       trace log whenever a DBI or handle trace() method is called.  The
1690       process id also shown for every method call if the DBI trace level (not
1691       handle trace level) is set high enough to show the trace from the DBI's
1692       method dispatcher, e.g. >= 9.
1693
1694       "AutoInactiveDestroy"
1695
1696       Type: boolean, inherited
1697
1698       The "InactiveDestroy" attribute, described above, needs to be
1699       explicitly set in the child process after a fork(), on every active
1700       database and statement handle.  This is a problem if the code that
1701       performs the fork() is not under your control, perhaps in a third-party
1702       module.  Use "AutoInactiveDestroy" to get around this situation.
1703
1704       If set true, the DESTROY method will check the process id of the handle
1705       and, if different from the current process id, it will set the
1706       InactiveDestroy attribute.  It is strongly recommended that
1707       "AutoInactiveDestroy" is enabled on all new code (it's only not enabled
1708       by default to avoid backwards compatibility problems).
1709
1710       This is the example it's designed to deal with:
1711
1712           my $dbh = DBI->connect(...);
1713           some_code_that_forks(); # Perhaps without your knowledge
1714           # Child process dies, destroying the inherited dbh
1715           $dbh->do(...); # Breaks because parent $dbh is now broken
1716
1717       The "AutoInactiveDestroy" attribute was added in DBI 1.614.
1718
1719       "PrintWarn"
1720
1721       Type: boolean, inherited
1722
1723       The "PrintWarn" attribute controls the printing of warnings recorded by
1724       the driver.  When set to a true value (the default) the DBI will check
1725       method calls to see if a warning condition has been set. If so, the DBI
1726       will effectively do a "warn("$class $method warning: $DBI::errstr")"
1727       where $class is the driver class and $method is the name of the method
1728       which failed. E.g.,
1729
1730         DBD::Oracle::db execute warning: ... warning text here ...
1731
1732       If desired, the warnings can be caught and processed using a
1733       $SIG{__WARN__} handler or modules like CGI::Carp and CGI::ErrorWrap.
1734
1735       See also "set_err" for how warnings are recorded and "HandleSetErr" for
1736       how to influence it.
1737
1738       Fetching the full details of warnings can require an extra round-trip
1739       to the database server for some drivers. In which case the driver may
1740       opt to only fetch the full details of warnings if the "PrintWarn"
1741       attribute is true. If "PrintWarn" is false then these drivers should
1742       still indicate the fact that there were warnings by setting the warning
1743       string to, for example: "3 warnings".
1744
1745       "PrintError"
1746
1747       Type: boolean, inherited
1748
1749       The "PrintError" attribute can be used to force errors to generate
1750       warnings (using "warn") in addition to returning error codes in the
1751       normal way.  When set "on", any method which results in an error
1752       occurring will cause the DBI to effectively do a "warn("$class $method
1753       failed: $DBI::errstr")" where $class is the driver class and $method is
1754       the name of the method which failed. E.g.,
1755
1756         DBD::Oracle::db prepare failed: ... error text here ...
1757
1758       By default, "DBI->connect" sets "PrintError" "on".
1759
1760       If desired, the warnings can be caught and processed using a
1761       $SIG{__WARN__} handler or modules like CGI::Carp and CGI::ErrorWrap.
1762
1763       "RaiseError"
1764
1765       Type: boolean, inherited
1766
1767       The "RaiseError" attribute can be used to force errors to raise
1768       exceptions rather than simply return error codes in the normal way. It
1769       is "off" by default.  When set "on", any method which results in an
1770       error will cause the DBI to effectively do a "die("$class $method
1771       failed: $DBI::errstr")", where $class is the driver class and $method
1772       is the name of the method that failed. E.g.,
1773
1774         DBD::Oracle::db prepare failed: ... error text here ...
1775
1776       If you turn "RaiseError" on then you'd normally turn "PrintError" off.
1777       If "PrintError" is also on, then the "PrintError" is done first
1778       (naturally).
1779
1780       Typically "RaiseError" is used in conjunction with "eval", or a module
1781       like Try::Tiny or TryCatch, to catch the exception that's been thrown
1782       and handle it.  For example:
1783
1784         use Try::Tiny;
1785
1786         try {
1787           ...
1788           $sth->execute();
1789           ...
1790         } catch {
1791           # $sth->err and $DBI::err will be true if error was from DBI
1792           warn $_; # print the error (which Try::Tiny puts into $_)
1793           ... # do whatever you need to deal with the error
1794         };
1795
1796       In the catch block the $DBI::lasth variable can be useful for diagnosis
1797       and reporting if you can't be sure which handle triggered the error.
1798       For example, $DBI::lasth->{Type} and $DBI::lasth->{Statement}.
1799
1800       See also "Transactions".
1801
1802       If you want to temporarily turn "RaiseError" off (inside a library
1803       function that is likely to fail, for example), the recommended way is
1804       like this:
1805
1806         {
1807           local $h->{RaiseError};  # localize and turn off for this block
1808           ...
1809         }
1810
1811       The original value will automatically and reliably be restored by Perl,
1812       regardless of how the block is exited.  The same logic applies to other
1813       attributes, including "PrintError".
1814
1815       "HandleError"
1816
1817       Type: code ref, inherited
1818
1819       The "HandleError" attribute can be used to provide your own alternative
1820       behaviour in case of errors. If set to a reference to a subroutine then
1821       that subroutine is called when an error is detected (at the same point
1822       that "RaiseError" and "PrintError" are handled).
1823
1824       The subroutine is called with three parameters: the error message
1825       string that "RaiseError" and "PrintError" would use, the DBI handle
1826       being used, and the first value being returned by the method that
1827       failed (typically undef).
1828
1829       If the subroutine returns a false value then the "RaiseError" and/or
1830       "PrintError" attributes are checked and acted upon as normal.
1831
1832       For example, to "die" with a full stack trace for any error:
1833
1834         use Carp;
1835         $h->{HandleError} = sub { confess(shift) };
1836
1837       Or to turn errors into exceptions:
1838
1839         use Exception; # or your own favourite exception module
1840         $h->{HandleError} = sub { Exception->new('DBI')->raise($_[0]) };
1841
1842       It is possible to 'stack' multiple HandleError handlers by using
1843       closures:
1844
1845         sub your_subroutine {
1846           my $previous_handler = $h->{HandleError};
1847           $h->{HandleError} = sub {
1848             return 1 if $previous_handler and &$previous_handler(@_);
1849             ... your code here ...
1850           };
1851         }
1852
1853       Using a "my" inside a subroutine to store the previous "HandleError"
1854       value is important.  See perlsub and perlref for more information about
1855       closures.
1856
1857       It is possible for "HandleError" to alter the error message that will
1858       be used by "RaiseError" and "PrintError" if it returns false.  It can
1859       do that by altering the value of $_[0]. This example appends a stack
1860       trace to all errors and, unlike the previous example using
1861       Carp::confess, this will work "PrintError" as well as "RaiseError":
1862
1863         $h->{HandleError} = sub { $_[0]=Carp::longmess($_[0]); 0; };
1864
1865       It is also possible for "HandleError" to hide an error, to a limited
1866       degree, by using "set_err" to reset $DBI::err and $DBI::errstr, and
1867       altering the return value of the failed method. For example:
1868
1869         $h->{HandleError} = sub {
1870           return 0 unless $_[0] =~ /^\S+ fetchrow_arrayref failed:/;
1871           return 0 unless $_[1]->err == 1234; # the error to 'hide'
1872           $h->set_err(undef,undef);   # turn off the error
1873           $_[2] = [ ... ];    # supply alternative return value
1874           return 1;
1875         };
1876
1877       This only works for methods which return a single value and is hard to
1878       make reliable (avoiding infinite loops, for example) and so isn't
1879       recommended for general use!  If you find a good use for it then please
1880       let me know.
1881
1882       "HandleSetErr"
1883
1884       Type: code ref, inherited
1885
1886       The "HandleSetErr" attribute can be used to intercept the setting of
1887       handle "err", "errstr", and "state" values.  If set to a reference to a
1888       subroutine then that subroutine is called whenever set_err() is called,
1889       typically by the driver or a subclass.
1890
1891       The subroutine is called with five arguments, the first five that were
1892       passed to set_err(): the handle, the "err", "errstr", and "state"
1893       values being set, and the method name. These can be altered by changing
1894       the values in the @_ array. The return value affects set_err()
1895       behaviour, see "set_err" for details.
1896
1897       It is possible to 'stack' multiple HandleSetErr handlers by using
1898       closures. See "HandleError" for an example.
1899
1900       The "HandleSetErr" and "HandleError" subroutines differ in subtle but
1901       significant ways. HandleError is only invoked at the point where the
1902       DBI is about to return to the application with "err" set true.  It's
1903       not invoked by the failure of a method that's been called by another
1904       DBI method.  HandleSetErr, on the other hand, is called whenever
1905       set_err() is called with a defined "err" value, even if false.  So it's
1906       not just for errors, despite the name, but also warn and info states.
1907       The set_err() method, and thus HandleSetErr, may be called multiple
1908       times within a method and is usually invoked from deep within driver
1909       code.
1910
1911       In theory a driver can use the return value from HandleSetErr via
1912       set_err() to decide whether to continue or not. If set_err() returns an
1913       empty list, indicating that the HandleSetErr code has 'handled' the
1914       'error', the driver could then continue instead of failing (if that's a
1915       reasonable thing to do).  This isn't excepted to be common and any such
1916       cases should be clearly marked in the driver documentation and
1917       discussed on the dbi-dev mailing list.
1918
1919       The "HandleSetErr" attribute was added in DBI 1.41.
1920
1921       "ErrCount"
1922
1923       Type: unsigned integer
1924
1925       The "ErrCount" attribute is incremented whenever the set_err() method
1926       records an error. It isn't incremented by warnings or information
1927       states. It is not reset by the DBI at any time.
1928
1929       The "ErrCount" attribute was added in DBI 1.41. Older drivers may not
1930       have been updated to use set_err() to record errors and so this
1931       attribute may not be incremented when using them.
1932
1933       "ShowErrorStatement"
1934
1935       Type: boolean, inherited
1936
1937       The "ShowErrorStatement" attribute can be used to cause the relevant
1938       Statement text to be appended to the error messages generated by the
1939       "RaiseError", "PrintError", and "PrintWarn" attributes.  Only applies
1940       to errors on statement handles plus the prepare(), do(), and the
1941       various "select*()" database handle methods.  (The exact format of the
1942       appended text is subject to change.)
1943
1944       If "$h->{ParamValues}" returns a hash reference of parameter
1945       (placeholder) values then those are formatted and appended to the end
1946       of the Statement text in the error message.
1947
1948       "TraceLevel"
1949
1950       Type: integer, inherited
1951
1952       The "TraceLevel" attribute can be used as an alternative to the "trace"
1953       method to set the DBI trace level and trace flags for a specific
1954       handle.  See "TRACING" for more details.
1955
1956       The "TraceLevel" attribute is especially useful combined with "local"
1957       to alter the trace settings for just a single block of code.
1958
1959       "FetchHashKeyName"
1960
1961       Type: string, inherited
1962
1963       The "FetchHashKeyName" attribute is used to specify whether the
1964       fetchrow_hashref() method should perform case conversion on the field
1965       names used for the hash keys. For historical reasons it defaults to
1966       '"NAME"' but it is recommended to set it to '"NAME_lc"' (convert to
1967       lower case) or '"NAME_uc"' (convert to upper case) according to your
1968       preference.  It can only be set for driver and database handles.  For
1969       statement handles the value is frozen when prepare() is called.
1970
1971       "ChopBlanks"
1972
1973       Type: boolean, inherited
1974
1975       The "ChopBlanks" attribute can be used to control the trimming of
1976       trailing space characters from fixed width character (CHAR) fields. No
1977       other field types are affected, even where field values have trailing
1978       spaces.
1979
1980       The default is false (although it is possible that the default may
1981       change).  Applications that need specific behaviour should set the
1982       attribute as needed.
1983
1984       Drivers are not required to support this attribute, but any driver
1985       which does not support it must arrange to return "undef" as the
1986       attribute value.
1987
1988       "LongReadLen"
1989
1990       Type: unsigned integer, inherited
1991
1992       The "LongReadLen" attribute may be used to control the maximum length
1993       of 'long' type fields (LONG, BLOB, CLOB, MEMO, etc.) which the driver
1994       will read from the database automatically when it fetches each row of
1995       data.
1996
1997       The "LongReadLen" attribute only relates to fetching and reading long
1998       values; it is not involved in inserting or updating them.
1999
2000       A value of 0 means not to automatically fetch any long data.  Drivers
2001       may return undef or an empty string for long fields when "LongReadLen"
2002       is 0.
2003
2004       The default is typically 0 (zero) or 80 bytes but may vary between
2005       drivers.  Applications fetching long fields should set this value to
2006       slightly larger than the longest long field value to be fetched.
2007
2008       Some databases return some long types encoded as pairs of hex digits.
2009       For these types, "LongReadLen" relates to the underlying data length
2010       and not the doubled-up length of the encoded string.
2011
2012       Changing the value of "LongReadLen" for a statement handle after it has
2013       been "prepare"'d will typically have no effect, so it's common to set
2014       "LongReadLen" on the $dbh before calling "prepare".
2015
2016       For most drivers the value used here has a direct effect on the memory
2017       used by the statement handle while it's active, so don't be too
2018       generous. If you can't be sure what value to use you could execute an
2019       extra select statement to determine the longest value.  For example:
2020
2021         $dbh->{LongReadLen} = $dbh->selectrow_array(qq{
2022             SELECT MAX(OCTET_LENGTH(long_column_name))
2023             FROM table WHERE ...
2024         });
2025         $sth = $dbh->prepare(qq{
2026             SELECT long_column_name, ... FROM table WHERE ...
2027         });
2028
2029       You may need to take extra care if the table can be modified between
2030       the first select and the second being executed. You may also need to
2031       use a different function if OCTET_LENGTH() does not work for long types
2032       in your database. For example, for Sybase use DATALENGTH() and for
2033       Oracle use LENGTHB().
2034
2035       See also "LongTruncOk" for information on truncation of long types.
2036
2037       "LongTruncOk"
2038
2039       Type: boolean, inherited
2040
2041       The "LongTruncOk" attribute may be used to control the effect of
2042       fetching a long field value which has been truncated (typically because
2043       it's longer than the value of the "LongReadLen" attribute).
2044
2045       By default, "LongTruncOk" is false and so fetching a long value that
2046       needs to be truncated will cause the fetch to fail.  (Applications
2047       should always be sure to check for errors after a fetch loop in case an
2048       error, such as a divide by zero or long field truncation, caused the
2049       fetch to terminate prematurely.)
2050
2051       If a fetch fails due to a long field truncation when "LongTruncOk" is
2052       false, many drivers will allow you to continue fetching further rows.
2053
2054       See also "LongReadLen".
2055
2056       "TaintIn"
2057
2058       Type: boolean, inherited
2059
2060       If the "TaintIn" attribute is set to a true value and Perl is running
2061       in taint mode (e.g., started with the "-T" option), then all the
2062       arguments to most DBI method calls are checked for being tainted. This
2063       may change.
2064
2065       The attribute defaults to off, even if Perl is in taint mode.  See
2066       perlsec for more about taint mode.  If Perl is not running in taint
2067       mode, this attribute has no effect.
2068
2069       When fetching data that you trust you can turn off the TaintIn
2070       attribute, for that statement handle, for the duration of the fetch
2071       loop.
2072
2073       The "TaintIn" attribute was added in DBI 1.31.
2074
2075       "TaintOut"
2076
2077       Type: boolean, inherited
2078
2079       If the "TaintOut" attribute is set to a true value and Perl is running
2080       in taint mode (e.g., started with the "-T" option), then most data
2081       fetched from the database is considered tainted. This may change.
2082
2083       The attribute defaults to off, even if Perl is in taint mode.  See
2084       perlsec for more about taint mode.  If Perl is not running in taint
2085       mode, this attribute has no effect.
2086
2087       When fetching data that you trust you can turn off the TaintOut
2088       attribute, for that statement handle, for the duration of the fetch
2089       loop.
2090
2091       Currently only fetched data is tainted. It is possible that the results
2092       of other DBI method calls, and the value of fetched attributes, may
2093       also be tainted in future versions. That change may well break your
2094       applications unless you take great care now. If you use DBI Taint mode,
2095       please report your experience and any suggestions for changes.
2096
2097       The "TaintOut" attribute was added in DBI 1.31.
2098
2099       "Taint"
2100
2101       Type: boolean, inherited
2102
2103       The "Taint" attribute is a shortcut for "TaintIn" and "TaintOut" (it is
2104       also present for backwards compatibility).
2105
2106       Setting this attribute sets both "TaintIn" and "TaintOut", and
2107       retrieving it returns a true value if and only if "TaintIn" and
2108       "TaintOut" are both set to true values.
2109
2110       "Profile"
2111
2112       Type: inherited
2113
2114       The "Profile" attribute enables the collection and reporting of method
2115       call timing statistics.  See the DBI::Profile module documentation for
2116       much more detail.
2117
2118       The "Profile" attribute was added in DBI 1.24.
2119
2120       "ReadOnly"
2121
2122       Type: boolean, inherited
2123
2124       An application can set the "ReadOnly" attribute of a handle to a true
2125       value to indicate that it will not be attempting to make any changes
2126       using that handle or any children of it.
2127
2128       Note that the exact definition of 'read only' is rather fuzzy.  For
2129       more details see the documentation for the driver you're using.
2130
2131       If the driver can make the handle truly read-only then it should
2132       (unless doing so would have unpleasant side effect, like changing the
2133       consistency level from per-statement to per-session).  Otherwise the
2134       attribute is simply advisory.
2135
2136       A driver can set the "ReadOnly" attribute itself to indicate that the
2137       data it is connected to cannot be changed for some reason.
2138
2139       If the driver cannot ensure the "ReadOnly" attribute is adhered to it
2140       will record a warning.  In this case reading the "ReadOnly" attribute
2141       back after it is set true will return true even if the underlying
2142       driver cannot ensure this (so any application knows the application
2143       declared itself ReadOnly).
2144
2145       Library modules and proxy drivers can use the attribute to influence
2146       their behavior.  For example, the DBD::Gofer driver considers the
2147       "ReadOnly" attribute when making a decision about whether to retry an
2148       operation that failed.
2149
2150       The attribute should be set to 1 or 0 (or undef). Other values are
2151       reserved.
2152
2153       "Callbacks"
2154
2155       Type: hash ref
2156
2157       The DBI callback mechanism lets you intercept, and optionally replace,
2158       any method call on a DBI handle. At the extreme, it lets you become a
2159       puppet master, deceiving the application in any way you want.
2160
2161       The "Callbacks" attribute is a hash reference where the keys are DBI
2162       method names and the values are code references. For each key naming a
2163       method, the DBI will execute the associated code reference before
2164       executing the method.
2165
2166       The arguments to the code reference will be the same as to the method,
2167       including the invocant (a database handle or statement handle). For
2168       example, say that to callback to some code on a call to "prepare()":
2169
2170         $dbh->{Callbacks} = {
2171             prepare => sub {
2172                 my ($dbh, $query, $attrs) = @_;
2173                 print "Preparing q{$query}\n"
2174             },
2175         };
2176
2177       The callback would then be executed when you called the "prepare()"
2178       method:
2179
2180         $dbh->prepare('SELECT 1');
2181
2182       And the output of course would be:
2183
2184         Preparing q{SELECT 1}
2185
2186       Because callbacks are executed before the methods they're associated
2187       with, you can modify the arguments before they're passed on to the
2188       method call. For example, to make sure that all calls to "prepare()"
2189       are immediately prepared by DBD::Pg, add a callback that makes sure
2190       that the "pg_prepare_now" attribute is always set:
2191
2192         my $dbh = DBI->connect($dsn, $username, $auth, {
2193             Callbacks => {
2194                 prepare => sub {
2195                     $_[2] ||= {};
2196                     $_[2]->{pg_prepare_now} = 1;
2197                     return; # must return nothing
2198                 },
2199             }
2200         });
2201
2202       Note that we are editing the contents of @_ directly. In this case
2203       we've created the attributes hash if it's not passed to the "prepare"
2204       call.
2205
2206       You can also prevent the associated method from ever executing. While a
2207       callback executes, $_ holds the method name. (This allows multiple
2208       callbacks to share the same code reference and still know what method
2209       was called.)  To prevent the method from executing, simply "undef $_".
2210       For example, if you wanted to disable calls to "ping()", you could do
2211       this:
2212
2213         $dbh->{Callbacks} = {
2214             ping => sub {
2215                 # tell dispatch to not call the method:
2216                 undef $_;
2217                 # return this value instead:
2218                 return "42 bells";
2219             }
2220         };
2221
2222       As with other attributes, Callbacks can be specified on a handle or via
2223       the attributes to "connect()". Callbacks can also be applied to a
2224       statement methods on a statement handle. For example:
2225
2226         $sth->{Callbacks} = {
2227             execute => sub {
2228                 print "Executing ", shift->{Statement}, "\n";
2229             }
2230         };
2231
2232       The "Callbacks" attribute of a database handle isn't copied to any
2233       statement handles it creates. So setting callbacks for a statement
2234       handle requires you to set the "Callbacks" attribute on the statement
2235       handle yourself, as in the example above, or use the special
2236       "ChildCallbacks" key described below.
2237
2238       Special Keys in Callbacks Attribute
2239
2240       In addition to DBI handle method names, the "Callbacks" hash reference
2241       supports four additional keys.
2242
2243       The first is the "ChildCallbacks" key. When a statement handle is
2244       created from a database handle the "ChildCallbacks" key of the database
2245       handle's "Callbacks" attribute, if any, becomes the new "Callbacks"
2246       attribute of the statement handle.  This allows you to define callbacks
2247       for all statement handles created from a database handle. For example,
2248       if you wanted to count how many times "execute" was called in your
2249       application, you could write:
2250
2251         my $exec_count = 0;
2252         my $dbh = DBI->connect( $dsn, $username, $auth, {
2253             Callbacks => {
2254                 ChildCallbacks => {
2255                     execute => sub { $exec_count++; return; }
2256                 }
2257             }
2258         });
2259
2260         END {
2261             print "The execute method was called $exec_count times\n";
2262         }
2263
2264       The other three special keys are "connect_cached.new",
2265       "connect_cached.connected", and "connect_cached.reused". These keys
2266       define callbacks that are called when "connect_cached()" is called, but
2267       allow different behaviors depending on whether a new handle is created
2268       or a handle is returned. The callback is invoked with these arguments:
2269       "$dbh, $dsn, $user, $auth, $attr".
2270
2271       For example, some applications uses "connect_cached()" to connect with
2272       "AutoCommit" enabled and then disable "AutoCommit" temporarily for
2273       transactions. If "connect_cached()" is called during a transaction,
2274       perhaps in a utility method, then it might select the same cached
2275       handle and then force "AutoCommit" on, forcing a commit of the
2276       transaction. See the "connect_cached" documentation for one way to deal
2277       with that. Here we'll describe an alternative approach using a
2278       callback.
2279
2280       Because the "connect_cached.new" and "connect_cached.reused" callbacks
2281       are invoked before "connect_cached()" has applied the connect
2282       attributes, you can use them to edit the attributes that will be
2283       applied. To prevent a cached handle from having its transactions
2284       committed before it's returned, you can eliminate the "AutoCommit"
2285       attribute in a "connect_cached.reused" callback, like so:
2286
2287         my $cb = {
2288             'connect_cached.reused' => sub { delete $_[4]->{AutoCommit} },
2289         };
2290
2291         sub dbh {
2292             my $self = shift;
2293             DBI->connect_cached( $dsn, $username, $auth, {
2294                 PrintError => 0,
2295                 RaiseError => 1,
2296                 AutoCommit => 1,
2297                 Callbacks  => $cb,
2298             });
2299         }
2300
2301       The upshot is that new database handles are created with "AutoCommit"
2302       enabled, while cached database handles are left in whatever transaction
2303       state they happened to be in when retrieved from the cache.
2304
2305       Note that we've also used a lexical for the callbacks hash reference.
2306       This is because "connect_cached()" returns a new database handle if any
2307       of the attributes passed to is have changed. If we used an inline hash
2308       reference, "connect_cached()" would return a new database handle every
2309       time. Which would rather defeat the purpose.
2310
2311       A more common application for callbacks is setting connection state
2312       only when a new connection is made (by connect() or connect_cached()).
2313       Adding a callback to the connected method (when using "connect") or via
2314       "connect_cached.connected" (when useing connect_cached()>) makes this
2315       easy.  The connected() method is a no-op by default (unless you
2316       subclass the DBI and change it). The DBI calls it to indicate that a
2317       new connection has been made and the connection attributes have all
2318       been set. You can give it a bit of added functionality by applying a
2319       callback to it. For example, to make sure that MySQL understands your
2320       application's ANSI-compliant SQL, set it up like so:
2321
2322         my $dbh = DBI->connect($dsn, $username, $auth, {
2323             Callbacks => {
2324                 connected => sub {
2325                     shift->do(q{
2326                         SET SESSION sql_mode='ansi,strict_trans_tables,no_auto_value_on_zero';
2327                     });
2328                     return;
2329                 },
2330             }
2331         });
2332
2333       If you're using "connect_cached()", use the "connect_cached.connected"
2334       callback, instead. This is because "connected()" is called for both new
2335       and reused database handles, but you want to execute a callback only
2336       the when a new database handle is returned. For example, to set the
2337       time zone on connection to a PostgreSQL database, try this:
2338
2339         my $cb = {
2340             'connect_cached.connected' => sub {
2341                 shift->do('SET timezone = UTC');
2342             }
2343         };
2344
2345         sub dbh {
2346             my $self = shift;
2347             DBI->connect_cached( $dsn, $username, $auth, { Callbacks => $cb });
2348         }
2349
2350       One significant limitation with callbacks is that there can only be one
2351       per method per handle. This means it's easy for one use of callbacks to
2352       interfere with, or typically simply overwrite, another use of
2353       callbacks. For this reason modules using callbacks should document the
2354       fact clearly so application authors can tell if use of callbacks by the
2355       module will clash with use of callbacks by the application.
2356
2357       You might be able to work around this issue by taking a copy of the
2358       original callback and calling it within your own. For example:
2359
2360         my $prev_cb = $h->{Callbacks}{method_name};
2361         $h->{Callbacks}{method_name} = sub {
2362           if ($prev_cb) {
2363               my @result = $prev_cb->(@_);
2364               return @result if not $_; # $prev_cb vetoed call
2365           }
2366           ... your callback logic here ...
2367         };
2368
2369       "private_your_module_name_*"
2370
2371       The DBI provides a way to store extra information in a DBI handle as
2372       "private" attributes. The DBI will allow you to store and retrieve any
2373       attribute which has a name starting with ""private_"".
2374
2375       It is strongly recommended that you use just one private attribute
2376       (e.g., use a hash ref) and give it a long and unambiguous name that
2377       includes the module or application name that the attribute relates to
2378       (e.g., ""private_YourFullModuleName_thingy"").
2379
2380       Because of the way the Perl tie mechanism works you cannot reliably use
2381       the "||=" operator directly to initialise the attribute, like this:
2382
2383         my $foo = $dbh->{private_yourmodname_foo} ||= { ... }; # WRONG
2384
2385       you should use a two step approach like this:
2386
2387         my $foo = $dbh->{private_yourmodname_foo};
2388         $foo ||= $dbh->{private_yourmodname_foo} = { ... };
2389
2390       This attribute is primarily of interest to people sub-classing DBI, or
2391       for applications to piggy-back extra information onto DBI handles.
2392

DBI DATABASE HANDLE OBJECTS

2394       This section covers the methods and attributes associated with database
2395       handles.
2396
2397   Database Handle Methods
2398       The following methods are specified for DBI database handles:
2399
2400       "clone"
2401
2402         $new_dbh = $dbh->clone(\%attr);
2403
2404       The "clone" method duplicates the $dbh connection by connecting with
2405       the same parameters ($dsn, $user, $password) as originally used.
2406
2407       The attributes for the cloned connect are the same as those used for
2408       the original connect, with any other attributes in "\%attr" merged over
2409       them.  Effectively the same as doing:
2410
2411         %attributes_used = ( %original_attributes, %attr );
2412
2413       If \%attr is not given then it defaults to a hash containing all the
2414       attributes in the attribute cache of $dbh excluding any non-code
2415       references, plus the main boolean attributes (RaiseError, PrintError,
2416       AutoCommit, etc.). This behaviour is unreliable and so use of clone
2417       without an argument is deprecated and may cause a warning in a future
2418       release.
2419
2420       The clone method can be used even if the database handle is
2421       disconnected.
2422
2423       The "clone" method was added in DBI 1.33.
2424
2425       "data_sources"
2426
2427         @ary = $dbh->data_sources();
2428         @ary = $dbh->data_sources(\%attr);
2429
2430       Returns a list of data sources (databases) available via the $dbh
2431       driver's data_sources() method, plus any extra data sources that the
2432       driver can discover via the connected $dbh. Typically the extra data
2433       sources are other databases managed by the same server process that the
2434       $dbh is connected to.
2435
2436       Data sources are returned in a form suitable for passing to the
2437       "connect" method (that is, they will include the ""dbi:$driver:""
2438       prefix).
2439
2440       The data_sources() method, for a $dbh, was added in DBI 1.38.
2441
2442       "do"
2443
2444         $rows = $dbh->do($statement)           or die $dbh->errstr;
2445         $rows = $dbh->do($statement, \%attr)   or die $dbh->errstr;
2446         $rows = $dbh->do($statement, \%attr, @bind_values) or die ...
2447
2448       Prepare and execute a single statement. Returns the number of rows
2449       affected or "undef" on error. A return value of "-1" means the number
2450       of rows is not known, not applicable, or not available.
2451
2452       This method is typically most useful for non-"SELECT" statements that
2453       either cannot be prepared in advance (due to a limitation of the
2454       driver) or do not need to be executed repeatedly. It should not be used
2455       for "SELECT" statements because it does not return a statement handle
2456       (so you can't fetch any data).
2457
2458       The default "do" method is logically similar to:
2459
2460         sub do {
2461             my($dbh, $statement, $attr, @bind_values) = @_;
2462             my $sth = $dbh->prepare($statement, $attr) or return undef;
2463             $sth->execute(@bind_values) or return undef;
2464             my $rows = $sth->rows;
2465             ($rows == 0) ? "0E0" : $rows; # always return true if no error
2466         }
2467
2468       For example:
2469
2470         my $rows_deleted = $dbh->do(q{
2471             DELETE FROM table
2472             WHERE status = ?
2473         }, undef, 'DONE') or die $dbh->errstr;
2474
2475       Using placeholders and @bind_values with the "do" method can be useful
2476       because it avoids the need to correctly quote any variables in the
2477       $statement. But if you'll be executing the statement many times then
2478       it's more efficient to "prepare" it once and call "execute" many times
2479       instead.
2480
2481       The "q{...}" style quoting used in this example avoids clashing with
2482       quotes that may be used in the SQL statement. Use the double-quote-like
2483       "qq{...}" operator if you want to interpolate variables into the
2484       string.  See "Quote and Quote-like Operators" in perlop for more
2485       details.
2486
2487       Note drivers are free to avoid the overhead of creating an DBI
2488       statement handle for do(), especially if there are no parameters. In
2489       this case error handlers, if invoked during do(), will be passed the
2490       database handle.
2491
2492       "last_insert_id"
2493
2494         $rv = $dbh->last_insert_id();
2495         $rv = $dbh->last_insert_id($catalog, $schema, $table, $field);
2496         $rv = $dbh->last_insert_id($catalog, $schema, $table, $field, \%attr);
2497
2498       Returns a value 'identifying' the row just inserted, if possible.
2499       Typically this would be a value assigned by the database server to a
2500       column with an auto_increment or serial type.  Returns undef if the
2501       driver does not support the method or can't determine the value.
2502
2503       The $catalog, $schema, $table, and $field parameters may be required
2504       for some drivers (see below).  If you don't know the parameter values
2505       and your driver does not need them, then use "undef" for each.
2506
2507       There are several caveats to be aware of with this method if you want
2508       to use it for portable applications:
2509
2510       * For some drivers the value may only available immediately after the
2511       insert statement has executed (e.g., mysql, Informix).
2512
2513       * For some drivers the $catalog, $schema, $table, and $field parameters
2514       are required, for others they are ignored (e.g., mysql).
2515
2516       * Drivers may return an indeterminate value if no insert has been
2517       performed yet.
2518
2519       * For some drivers the value may only be available if placeholders have
2520       not been used (e.g., Sybase, MS SQL). In this case the value returned
2521       would be from the last non-placeholder insert statement.
2522
2523       * Some drivers may need driver-specific hints about how to get the
2524       value. For example, being told the name of the database 'sequence'
2525       object that holds the value. Any such hints are passed as driver-
2526       specific attributes in the \%attr parameter.
2527
2528       * If the underlying database offers nothing better, then some drivers
2529       may attempt to implement this method by executing ""select max($field)
2530       from $table"". Drivers using any approach like this should issue a
2531       warning if "AutoCommit" is true because it is generally unsafe -
2532       another process may have modified the table between your insert and the
2533       select. For situations where you know it is safe, such as when you have
2534       locked the table, you can silence the warning by passing "Warn" => 0 in
2535       \%attr.
2536
2537       * If no insert has been performed yet, or the last insert failed, then
2538       the value is implementation defined.
2539
2540       Given all the caveats above, it's clear that this method must be used
2541       with care.
2542
2543       The "last_insert_id" method was added in DBI 1.38.
2544
2545       "selectrow_array"
2546
2547         @row_ary = $dbh->selectrow_array($statement);
2548         @row_ary = $dbh->selectrow_array($statement, \%attr);
2549         @row_ary = $dbh->selectrow_array($statement, \%attr, @bind_values);
2550
2551       This utility method combines "prepare", "execute" and "fetchrow_array"
2552       into a single call. If called in a list context, it returns the first
2553       row of data from the statement.  The $statement parameter can be a
2554       previously prepared statement handle, in which case the "prepare" is
2555       skipped.
2556
2557       If any method fails, and "RaiseError" is not set, "selectrow_array"
2558       will return an empty list.
2559
2560       If called in a scalar context for a statement handle that has more than
2561       one column, it is undefined whether the driver will return the value of
2562       the first column or the last. So don't do that.  Also, in a scalar
2563       context, an "undef" is returned if there are no more rows or if an
2564       error occurred. That "undef" can't be distinguished from an "undef"
2565       returned because the first field value was NULL.  For these reasons you
2566       should exercise some caution if you use "selectrow_array" in a scalar
2567       context, or just don't do that.
2568
2569       "selectrow_arrayref"
2570
2571         $ary_ref = $dbh->selectrow_arrayref($statement);
2572         $ary_ref = $dbh->selectrow_arrayref($statement, \%attr);
2573         $ary_ref = $dbh->selectrow_arrayref($statement, \%attr, @bind_values);
2574
2575       This utility method combines "prepare", "execute" and
2576       "fetchrow_arrayref" into a single call. It returns the first row of
2577       data from the statement.  The $statement parameter can be a previously
2578       prepared statement handle, in which case the "prepare" is skipped.
2579
2580       If any method fails, and "RaiseError" is not set, "selectrow_arrayref"
2581       will return undef.
2582
2583       "selectrow_hashref"
2584
2585         $hash_ref = $dbh->selectrow_hashref($statement);
2586         $hash_ref = $dbh->selectrow_hashref($statement, \%attr);
2587         $hash_ref = $dbh->selectrow_hashref($statement, \%attr, @bind_values);
2588
2589       This utility method combines "prepare", "execute" and
2590       "fetchrow_hashref" into a single call. It returns the first row of data
2591       from the statement.  The $statement parameter can be a previously
2592       prepared statement handle, in which case the "prepare" is skipped.
2593
2594       If any method fails, and "RaiseError" is not set, "selectrow_hashref"
2595       will return undef.
2596
2597       "selectall_arrayref"
2598
2599         $ary_ref = $dbh->selectall_arrayref($statement);
2600         $ary_ref = $dbh->selectall_arrayref($statement, \%attr);
2601         $ary_ref = $dbh->selectall_arrayref($statement, \%attr, @bind_values);
2602
2603       This utility method combines "prepare", "execute" and
2604       "fetchall_arrayref" into a single call. It returns a reference to an
2605       array containing a reference to an array (or hash, see below) for each
2606       row of data fetched.
2607
2608       The $statement parameter can be a previously prepared statement handle,
2609       in which case the "prepare" is skipped. This is recommended if the
2610       statement is going to be executed many times.
2611
2612       If "RaiseError" is not set and any method except "fetchall_arrayref"
2613       fails then "selectall_arrayref" will return "undef"; if
2614       "fetchall_arrayref" fails then it will return with whatever data has
2615       been fetched thus far. You should check "$dbh->err" afterwards (or use
2616       the "RaiseError" attribute) to discover if the data is complete or was
2617       truncated due to an error.
2618
2619       The "fetchall_arrayref" method called by "selectall_arrayref" supports
2620       a $max_rows parameter. You can specify a value for $max_rows by
2621       including a '"MaxRows"' attribute in \%attr. In which case finish() is
2622       called for you after fetchall_arrayref() returns.
2623
2624       The "fetchall_arrayref" method called by "selectall_arrayref" also
2625       supports a $slice parameter. You can specify a value for $slice by
2626       including a '"Slice"' or '"Columns"' attribute in \%attr. The only
2627       difference between the two is that if "Slice" is not defined and
2628       "Columns" is an array ref, then the array is assumed to contain column
2629       index values (which count from 1), rather than perl array index values.
2630       In which case the array is copied and each value decremented before
2631       passing to "/fetchall_arrayref".
2632
2633       You may often want to fetch an array of rows where each row is stored
2634       as a hash. That can be done simply using:
2635
2636         my $emps = $dbh->selectall_arrayref(
2637             "SELECT ename FROM emp ORDER BY ename",
2638             { Slice => {} }
2639         );
2640         foreach my $emp ( @$emps ) {
2641             print "Employee: $emp->{ename}\n";
2642         }
2643
2644       Or, to fetch into an array instead of an array ref:
2645
2646         @result = @{ $dbh->selectall_arrayref($sql, { Slice => {} }) };
2647
2648       See "fetchall_arrayref" method for more details.
2649
2650       "selectall_array"
2651
2652         @ary = $dbh->selectall_array($statement);
2653         @ary = $dbh->selectall_array($statement, \%attr);
2654         @ary = $dbh->selectall_array($statement, \%attr, @bind_values);
2655
2656       This is a convenience wrapper around selectall_arrayref that returns
2657       the rows directly as a list, rather than a reference to an array of
2658       rows.
2659
2660       Note that if "RaiseError" is not set then you can't tell the difference
2661       between returning no rows and an error. Using RaiseError is best
2662       practice.
2663
2664       "selectall_hashref"
2665
2666         $hash_ref = $dbh->selectall_hashref($statement, $key_field);
2667         $hash_ref = $dbh->selectall_hashref($statement, $key_field, \%attr);
2668         $hash_ref = $dbh->selectall_hashref($statement, $key_field, \%attr, @bind_values);
2669
2670       This utility method combines "prepare", "execute" and
2671       "fetchall_hashref" into a single call. It returns a reference to a hash
2672       containing one entry, at most, for each row, as returned by
2673       fetchall_hashref().
2674
2675       The $statement parameter can be a previously prepared statement handle,
2676       in which case the "prepare" is skipped.  This is recommended if the
2677       statement is going to be executed many times.
2678
2679       The $key_field parameter defines which column, or columns, are used as
2680       keys in the returned hash. It can either be the name of a single field,
2681       or a reference to an array containing multiple field names. Using
2682       multiple names yields a tree of nested hashes.
2683
2684       If a row has the same key as an earlier row then it replaces the
2685       earlier row.
2686
2687       If any method except "fetchall_hashref" fails, and "RaiseError" is not
2688       set, "selectall_hashref" will return "undef".  If "fetchall_hashref"
2689       fails and "RaiseError" is not set, then it will return with whatever
2690       data it has fetched thus far. $DBI::err should be checked to catch
2691       that.
2692
2693       See fetchall_hashref() for more details.
2694
2695       "selectcol_arrayref"
2696
2697         $ary_ref = $dbh->selectcol_arrayref($statement);
2698         $ary_ref = $dbh->selectcol_arrayref($statement, \%attr);
2699         $ary_ref = $dbh->selectcol_arrayref($statement, \%attr, @bind_values);
2700
2701       This utility method combines "prepare", "execute", and fetching one
2702       column from all the rows, into a single call. It returns a reference to
2703       an array containing the values of the first column from each row.
2704
2705       The $statement parameter can be a previously prepared statement handle,
2706       in which case the "prepare" is skipped. This is recommended if the
2707       statement is going to be executed many times.
2708
2709       If any method except "fetch" fails, and "RaiseError" is not set,
2710       "selectcol_arrayref" will return "undef".  If "fetch" fails and
2711       "RaiseError" is not set, then it will return with whatever data it has
2712       fetched thus far. $DBI::err should be checked to catch that.
2713
2714       The "selectcol_arrayref" method defaults to pushing a single column
2715       value (the first) from each row into the result array. However, it can
2716       also push another column, or even multiple columns per row, into the
2717       result array. This behaviour can be specified via a '"Columns"'
2718       attribute which must be a ref to an array containing the column number
2719       or numbers to use. For example:
2720
2721         # get array of id and name pairs:
2722         my $ary_ref = $dbh->selectcol_arrayref("select id, name from table", { Columns=>[1,2] });
2723         my %hash = @$ary_ref; # build hash from key-value pairs so $hash{$id} => name
2724
2725       You can specify a maximum number of rows to fetch by including a
2726       '"MaxRows"' attribute in \%attr.
2727
2728       "prepare"
2729
2730         $sth = $dbh->prepare($statement)          or die $dbh->errstr;
2731         $sth = $dbh->prepare($statement, \%attr)  or die $dbh->errstr;
2732
2733       Prepares a statement for later execution by the database engine and
2734       returns a reference to a statement handle object.
2735
2736       The returned statement handle can be used to get attributes of the
2737       statement and invoke the "execute" method. See "Statement Handle
2738       Methods".
2739
2740       Drivers for engines without the concept of preparing a statement will
2741       typically just store the statement in the returned handle and process
2742       it when "$sth->execute" is called. Such drivers are unlikely to give
2743       much useful information about the statement, such as
2744       "$sth->{NUM_OF_FIELDS}", until after "$sth->execute" has been called.
2745       Portable applications should take this into account.
2746
2747       In general, DBI drivers do not parse the contents of the statement
2748       (other than simply counting any Placeholders).  The statement is passed
2749       directly to the database engine, sometimes known as pass-thru mode.
2750       This has advantages and disadvantages. On the plus side, you can access
2751       all the functionality of the engine being used. On the downside, you're
2752       limited if you're using a simple engine, and you need to take extra
2753       care if writing applications intended to be portable between engines.
2754
2755       Portable applications should not assume that a new statement can be
2756       prepared and/or executed while still fetching results from a previous
2757       statement.
2758
2759       Some command-line SQL tools use statement terminators, like a
2760       semicolon, to indicate the end of a statement. Such terminators should
2761       not normally be used with the DBI.
2762
2763       "prepare_cached"
2764
2765         $sth = $dbh->prepare_cached($statement)
2766         $sth = $dbh->prepare_cached($statement, \%attr)
2767         $sth = $dbh->prepare_cached($statement, \%attr, $if_active)
2768
2769       Like "prepare" except that the statement handle returned will be stored
2770       in a hash associated with the $dbh. If another call is made to
2771       "prepare_cached" with the same $statement and %attr parameter values,
2772       then the corresponding cached $sth will be returned without contacting
2773       the database server. Be sure to understand the cautions and caveats
2774       noted below.
2775
2776       The $if_active parameter lets you adjust the behaviour if an already
2777       cached statement handle is still Active.  There are several
2778       alternatives:
2779
2780       0: A warning will be generated, and finish() will be called on the
2781       statement handle before it is returned.  This is the default behaviour
2782       if $if_active is not passed.
2783       1: finish() will be called on the statement handle, but the warning is
2784       suppressed.
2785       2: Disables any checking.
2786       3: The existing active statement handle will be removed from the cache
2787       and a new statement handle prepared and cached in its place. This is
2788       the safest option because it doesn't affect the state of the old
2789       handle, it just removes it from the cache. [Added in DBI 1.40]
2790
2791       Here are some examples of "prepare_cached":
2792
2793         sub insert_hash {
2794           my ($table, $field_values) = @_;
2795           # sort to keep field order, and thus sql, stable for prepare_cached
2796           my @fields = sort keys %$field_values;
2797           my @values = @{$field_values}{@fields};
2798           my $sql = sprintf "insert into %s (%s) values (%s)",
2799               $table, join(",", @fields), join(",", ("?")x@fields);
2800           my $sth = $dbh->prepare_cached($sql);
2801           return $sth->execute(@values);
2802         }
2803
2804         sub search_hash {
2805           my ($table, $field_values) = @_;
2806           # sort to keep field order, and thus sql, stable for prepare_cached
2807           my @fields = sort keys %$field_values;
2808           my @values = @{$field_values}{@fields};
2809           my $qualifier = "";
2810           $qualifier = "where ".join(" and ", map { "$_=?" } @fields) if @fields;
2811           $sth = $dbh->prepare_cached("SELECT * FROM $table $qualifier");
2812           return $dbh->selectall_arrayref($sth, {}, @values);
2813         }
2814
2815       Caveat emptor: This caching can be useful in some applications, but it
2816       can also cause problems and should be used with care. Here is a
2817       contrived case where caching would cause a significant problem:
2818
2819         my $sth = $dbh->prepare_cached('SELECT * FROM foo WHERE bar=?');
2820         $sth->execute(...);
2821         while (my $data = $sth->fetchrow_hashref) {
2822
2823           # later, in some other code called within the loop...
2824           my $sth2 = $dbh->prepare_cached('SELECT * FROM foo WHERE bar=?');
2825           $sth2->execute(...);
2826           while (my $data2 = $sth2->fetchrow_arrayref) {
2827             do_stuff(...);
2828           }
2829         }
2830
2831       In this example, since both handles are preparing the exact same
2832       statement, $sth2 will not be its own statement handle, but a duplicate
2833       of $sth returned from the cache. The results will certainly not be what
2834       you expect.  Typically the inner fetch loop will work normally,
2835       fetching all the records and terminating when there are no more, but
2836       now that $sth is the same as $sth2 the outer fetch loop will also
2837       terminate.
2838
2839       You'll know if you run into this problem because prepare_cached() will
2840       generate a warning by default (when $if_active is false).
2841
2842       The cache used by prepare_cached() is keyed by both the statement and
2843       any attributes so you can also avoid this issue by doing something
2844       like:
2845
2846         $sth = $dbh->prepare_cached("...", { dbi_dummy => __FILE__.__LINE__ });
2847
2848       which will ensure that prepare_cached only returns statements cached by
2849       that line of code in that source file.
2850
2851       Also, to ensure the attributes passed are always the same, avoid
2852       passing references inline. For example, the Slice attribute is
2853       specified as a reference. Be sure to declare it external to the call to
2854       prepare_cached(), such that a new hash reference is not created on
2855       every call. See "connect_cached" for more details and examples.
2856
2857       If you'd like the cache to managed intelligently, you can tie the
2858       hashref returned by "CachedKids" to an appropriate caching module, such
2859       as Tie::Cache::LRU:
2860
2861         my $cache;
2862         tie %$cache, 'Tie::Cache::LRU', 500;
2863         $dbh->{CachedKids} = $cache;
2864
2865       "commit"
2866
2867         $rc  = $dbh->commit     or die $dbh->errstr;
2868
2869       Commit (make permanent) the most recent series of database changes if
2870       the database supports transactions and AutoCommit is off.
2871
2872       If "AutoCommit" is on, then calling "commit" will issue a "commit
2873       ineffective with AutoCommit" warning.
2874
2875       See also "Transactions" in the "FURTHER INFORMATION" section below.
2876
2877       "rollback"
2878
2879         $rc  = $dbh->rollback   or die $dbh->errstr;
2880
2881       Rollback (undo) the most recent series of uncommitted database changes
2882       if the database supports transactions and AutoCommit is off.
2883
2884       If "AutoCommit" is on, then calling "rollback" will issue a "rollback
2885       ineffective with AutoCommit" warning.
2886
2887       See also "Transactions" in the "FURTHER INFORMATION" section below.
2888
2889       "begin_work"
2890
2891         $rc  = $dbh->begin_work   or die $dbh->errstr;
2892
2893       Enable transactions (by turning "AutoCommit" off) until the next call
2894       to "commit" or "rollback". After the next "commit" or "rollback",
2895       "AutoCommit" will automatically be turned on again.
2896
2897       If "AutoCommit" is already off when "begin_work" is called then it does
2898       nothing except return an error. If the driver does not support
2899       transactions then when "begin_work" attempts to set "AutoCommit" off
2900       the driver will trigger a fatal error.
2901
2902       See also "Transactions" in the "FURTHER INFORMATION" section below.
2903
2904       "disconnect"
2905
2906         $rc = $dbh->disconnect  or warn $dbh->errstr;
2907
2908       Disconnects the database from the database handle. "disconnect" is
2909       typically only used before exiting the program. The handle is of little
2910       use after disconnecting.
2911
2912       The transaction behaviour of the "disconnect" method is, sadly,
2913       undefined.  Some database systems (such as Oracle and Ingres) will
2914       automatically commit any outstanding changes, but others (such as
2915       Informix) will rollback any outstanding changes.  Applications not
2916       using "AutoCommit" should explicitly call "commit" or "rollback" before
2917       calling "disconnect".
2918
2919       The database is automatically disconnected by the "DESTROY" method if
2920       still connected when there are no longer any references to the handle.
2921       The "DESTROY" method for each driver should implicitly call "rollback"
2922       to undo any uncommitted changes. This is vital behaviour to ensure that
2923       incomplete transactions don't get committed simply because Perl calls
2924       "DESTROY" on every object before exiting. Also, do not rely on the
2925       order of object destruction during "global destruction", as it is
2926       undefined.
2927
2928       Generally, if you want your changes to be committed or rolled back when
2929       you disconnect, then you should explicitly call "commit" or "rollback"
2930       before disconnecting.
2931
2932       If you disconnect from a database while you still have active statement
2933       handles (e.g., SELECT statement handles that may have more data to
2934       fetch), you will get a warning. The warning may indicate that a fetch
2935       loop terminated early, perhaps due to an uncaught error.  To avoid the
2936       warning call the "finish" method on the active handles.
2937
2938       "ping"
2939
2940         $rc = $dbh->ping;
2941
2942       Attempts to determine, in a reasonably efficient way, if the database
2943       server is still running and the connection to it is still working.
2944       Individual drivers should implement this function in the most suitable
2945       manner for their database engine.
2946
2947       The current default implementation always returns true without actually
2948       doing anything. Actually, it returns ""0 but true"" which is true but
2949       zero. That way you can tell if the return value is genuine or just the
2950       default. Drivers should override this method with one that does the
2951       right thing for their type of database.
2952
2953       Few applications would have direct use for this method. See the
2954       specialized Apache::DBI module for one example usage.
2955
2956       "get_info"
2957
2958         $value = $dbh->get_info( $info_type );
2959
2960       Returns information about the implementation, i.e. driver and data
2961       source capabilities, restrictions etc. It returns "undef" for unknown
2962       or unimplemented information types. For example:
2963
2964         $database_version  = $dbh->get_info(  18 ); # SQL_DBMS_VER
2965         $max_select_tables = $dbh->get_info( 106 ); # SQL_MAXIMUM_TABLES_IN_SELECT
2966
2967       See "Standards Reference Information" for more detailed information
2968       about the information types and their meanings and possible return
2969       values.
2970
2971       The DBI::Const::GetInfoType module exports a %GetInfoType hash that can
2972       be used to map info type names to numbers. For example:
2973
2974         $database_version = $dbh->get_info( $GetInfoType{SQL_DBMS_VER} );
2975
2976       The names are a merging of the ANSI and ODBC standards (which differ in
2977       some cases). See DBI::Const::GetInfoType for more details.
2978
2979       Because some DBI methods make use of get_info(), drivers are strongly
2980       encouraged to support at least the following very minimal set of
2981       information types to ensure the DBI itself works properly:
2982
2983        Type  Name                        Example A     Example B
2984        ----  --------------------------  ------------  ----------------
2985          17  SQL_DBMS_NAME               'ACCESS'      'Oracle'
2986          18  SQL_DBMS_VER                '03.50.0000'  '08.01.0721 ...'
2987          29  SQL_IDENTIFIER_QUOTE_CHAR   '`'           '"'
2988          41  SQL_CATALOG_NAME_SEPARATOR  '.'           '@'
2989         114  SQL_CATALOG_LOCATION        1             2
2990
2991       Values from 9000 to 9999 for get_info are officially reserved for use
2992       by Perl DBI.  Values in that range which have been assigned a meaning
2993       are defined here:
2994
2995       9000: true if a backslash character ("\") before placeholder-like text
2996       (e.g. "?", ":foo") will prevent it being treated as a placeholder by
2997       the driver.  The backslash will be removed before the text is passed to
2998       the backend.
2999
3000       "table_info"
3001
3002         $sth = $dbh->table_info( $catalog, $schema, $table, $type );
3003         $sth = $dbh->table_info( $catalog, $schema, $table, $type, \%attr );
3004
3005         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3006
3007       Returns an active statement handle that can be used to fetch
3008       information about tables and views that exist in the database.
3009
3010       The arguments $catalog, $schema and $table may accept search patterns
3011       according to the database/driver, for example: $table = '%FOO%';
3012       Remember that the underscore character ('"_"') is a search pattern that
3013       means match any character, so 'FOO_%' is the same as 'FOO%' and
3014       'FOO_BAR%' will match names like 'FOO1BAR'.
3015
3016       The value of $type is a comma-separated list of one or more types of
3017       tables to be returned in the result set. Each value may optionally be
3018       quoted, e.g.:
3019
3020         $type = "TABLE";
3021         $type = "'TABLE','VIEW'";
3022
3023       In addition the following special cases may also be supported by some
3024       drivers:
3025
3026       ·   If the value of $catalog is '%' and $schema and $table name are
3027           empty strings, the result set contains a list of catalog names.
3028           For example:
3029
3030             $sth = $dbh->table_info('%', '', '');
3031
3032       ·   If the value of $schema is '%' and $catalog and $table are empty
3033           strings, the result set contains a list of schema names.
3034
3035       ·   If the value of $type is '%' and $catalog, $schema, and $table are
3036           all empty strings, the result set contains a list of table types.
3037
3038       If your driver doesn't support one or more of the selection filter
3039       parameters then you may get back more than you asked for and can do the
3040       filtering yourself.
3041
3042       This method can be expensive, and can return a large amount of data.
3043       (For example, small Oracle installation returns over 2000 rows.)  So
3044       it's a good idea to use the filters to limit the data as much as
3045       possible.
3046
3047       The statement handle returned has at least the following fields in the
3048       order show below. Other fields, after these, may also be present.
3049
3050       TABLE_CAT: Table catalog identifier. This field is NULL ("undef") if
3051       not applicable to the data source, which is usually the case. This
3052       field is empty if not applicable to the table.
3053
3054       TABLE_SCHEM: The name of the schema containing the TABLE_NAME value.
3055       This field is NULL ("undef") if not applicable to data source, and
3056       empty if not applicable to the table.
3057
3058       TABLE_NAME: Name of the table (or view, synonym, etc).
3059
3060       TABLE_TYPE: One of the following: "TABLE", "VIEW", "SYSTEM TABLE",
3061       "GLOBAL TEMPORARY", "LOCAL TEMPORARY", "ALIAS", "SYNONYM" or a type
3062       identifier that is specific to the data source.
3063
3064       REMARKS: A description of the table. May be NULL ("undef").
3065
3066       Note that "table_info" might not return records for all tables.
3067       Applications can use any valid table regardless of whether it's
3068       returned by "table_info".
3069
3070       See also "tables", "Catalog Methods" and "Standards Reference
3071       Information".
3072
3073       "column_info"
3074
3075         $sth = $dbh->column_info( $catalog, $schema, $table, $column );
3076
3077         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3078
3079       Returns an active statement handle that can be used to fetch
3080       information about columns in specified tables.
3081
3082       The arguments $schema, $table and $column may accept search patterns
3083       according to the database/driver, for example: $table = '%FOO%';
3084
3085       Note: The support for the selection criteria is driver specific. If the
3086       driver doesn't support one or more of them then you may get back more
3087       than you asked for and can do the filtering yourself.
3088
3089       Note: If your driver does not support column_info an undef is returned.
3090       This is distinct from asking for something which does not exist in a
3091       driver which supports column_info as a valid statement handle to an
3092       empty result-set will be returned in this case.
3093
3094       If the arguments don't match any tables then you'll still get a
3095       statement handle, it'll just return no rows.
3096
3097       The statement handle returned has at least the following fields in the
3098       order shown below. Other fields, after these, may also be present.
3099
3100       TABLE_CAT: The catalog identifier.  This field is NULL ("undef") if not
3101       applicable to the data source, which is often the case.  This field is
3102       empty if not applicable to the table.
3103
3104       TABLE_SCHEM: The schema identifier.  This field is NULL ("undef") if
3105       not applicable to the data source, and empty if not applicable to the
3106       table.
3107
3108       TABLE_NAME: The table identifier.  Note: A driver may provide column
3109       metadata not only for base tables, but also for derived objects like
3110       SYNONYMS etc.
3111
3112       COLUMN_NAME: The column identifier.
3113
3114       DATA_TYPE: The concise data type code.
3115
3116       TYPE_NAME: A data source dependent data type name.
3117
3118       COLUMN_SIZE: The column size.  This is the maximum length in characters
3119       for character data types, the number of digits or bits for numeric data
3120       types or the length in the representation of temporal types.  See the
3121       relevant specifications for detailed information.
3122
3123       BUFFER_LENGTH: The length in bytes of transferred data.
3124
3125       DECIMAL_DIGITS: The total number of significant digits to the right of
3126       the decimal point.
3127
3128       NUM_PREC_RADIX: The radix for numeric precision.  The value is 10 or 2
3129       for numeric data types and NULL ("undef") if not applicable.
3130
3131       NULLABLE: Indicates if a column can accept NULLs.  The following values
3132       are defined:
3133
3134         SQL_NO_NULLS          0
3135         SQL_NULLABLE          1
3136         SQL_NULLABLE_UNKNOWN  2
3137
3138       REMARKS: A description of the column.
3139
3140       COLUMN_DEF: The default value of the column, in a format that can be
3141       used directly in an SQL statement.
3142
3143       Note that this may be an expression and not simply the text used for
3144       the default value in the original CREATE TABLE statement. For example,
3145       given:
3146
3147           col1 char(30) default current_user    -- a 'function'
3148           col2 char(30) default 'string'        -- a string literal
3149
3150       where "current_user" is the name of a function, the corresponding
3151       "COLUMN_DEF" values would be:
3152
3153           Database        col1                     col2
3154           --------        ----                     ----
3155           Oracle:         current_user             'string'
3156           Postgres:       "current_user"()         'string'::text
3157           MS SQL:         (user_name())            ('string')
3158
3159       SQL_DATA_TYPE: The SQL data type.
3160
3161       SQL_DATETIME_SUB: The subtype code for datetime and interval data
3162       types.
3163
3164       CHAR_OCTET_LENGTH: The maximum length in bytes of a character or binary
3165       data type column.
3166
3167       ORDINAL_POSITION: The column sequence number (starting with 1).
3168
3169       IS_NULLABLE: Indicates if the column can accept NULLs.  Possible values
3170       are: 'NO', 'YES' and ''.
3171
3172       SQL/CLI defines the following additional columns:
3173
3174         CHAR_SET_CAT
3175         CHAR_SET_SCHEM
3176         CHAR_SET_NAME
3177         COLLATION_CAT
3178         COLLATION_SCHEM
3179         COLLATION_NAME
3180         UDT_CAT
3181         UDT_SCHEM
3182         UDT_NAME
3183         DOMAIN_CAT
3184         DOMAIN_SCHEM
3185         DOMAIN_NAME
3186         SCOPE_CAT
3187         SCOPE_SCHEM
3188         SCOPE_NAME
3189         MAX_CARDINALITY
3190         DTD_IDENTIFIER
3191         IS_SELF_REF
3192
3193       Drivers capable of supplying any of those values should do so in the
3194       corresponding column and supply undef values for the others.
3195
3196       Drivers wishing to provide extra database/driver specific information
3197       should do so in extra columns beyond all those listed above, and use
3198       lowercase field names with the driver-specific prefix (i.e.,
3199       'ora_...'). Applications accessing such fields should do so by name and
3200       not by column number.
3201
3202       The result set is ordered by TABLE_CAT, TABLE_SCHEM, TABLE_NAME and
3203       ORDINAL_POSITION.
3204
3205       Note: There is some overlap with statement handle attributes (in perl)
3206       and SQLDescribeCol (in ODBC). However, SQLColumns provides more
3207       metadata.
3208
3209       See also "Catalog Methods" and "Standards Reference Information".
3210
3211       "primary_key_info"
3212
3213         $sth = $dbh->primary_key_info( $catalog, $schema, $table );
3214
3215         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3216
3217       Returns an active statement handle that can be used to fetch
3218       information about columns that make up the primary key for a table.
3219       The arguments don't accept search patterns (unlike table_info()).
3220
3221       The statement handle will return one row per column, ordered by
3222       TABLE_CAT, TABLE_SCHEM, TABLE_NAME, and KEY_SEQ.  If there is no
3223       primary key then the statement handle will fetch no rows.
3224
3225       Note: The support for the selection criteria, such as $catalog, is
3226       driver specific.  If the driver doesn't support catalogs and/or
3227       schemas, it may ignore these criteria.
3228
3229       The statement handle returned has at least the following fields in the
3230       order shown below. Other fields, after these, may also be present.
3231
3232       TABLE_CAT: The catalog identifier.  This field is NULL ("undef") if not
3233       applicable to the data source, which is often the case.  This field is
3234       empty if not applicable to the table.
3235
3236       TABLE_SCHEM: The schema identifier.  This field is NULL ("undef") if
3237       not applicable to the data source, and empty if not applicable to the
3238       table.
3239
3240       TABLE_NAME: The table identifier.
3241
3242       COLUMN_NAME: The column identifier.
3243
3244       KEY_SEQ: The column sequence number (starting with 1).  Note: This
3245       field is named ORDINAL_POSITION in SQL/CLI.
3246
3247       PK_NAME: The primary key constraint identifier.  This field is NULL
3248       ("undef") if not applicable to the data source.
3249
3250       See also "Catalog Methods" and "Standards Reference Information".
3251
3252       "primary_key"
3253
3254         @key_column_names = $dbh->primary_key( $catalog, $schema, $table );
3255
3256       Simple interface to the primary_key_info() method. Returns a list of
3257       the column names that comprise the primary key of the specified table.
3258       The list is in primary key column sequence order.  If there is no
3259       primary key then an empty list is returned.
3260
3261       "foreign_key_info"
3262
3263         $sth = $dbh->foreign_key_info( $pk_catalog, $pk_schema, $pk_table
3264                                      , $fk_catalog, $fk_schema, $fk_table );
3265
3266         $sth = $dbh->foreign_key_info( $pk_catalog, $pk_schema, $pk_table
3267                                      , $fk_catalog, $fk_schema, $fk_table
3268                                      , \%attr );
3269
3270         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3271
3272       Returns an active statement handle that can be used to fetch
3273       information about foreign keys in and/or referencing the specified
3274       table(s).  The arguments don't accept search patterns (unlike
3275       table_info()).
3276
3277       $pk_catalog, $pk_schema, $pk_table identify the primary (unique) key
3278       table (PKT).
3279
3280       $fk_catalog, $fk_schema, $fk_table identify the foreign key table
3281       (FKT).
3282
3283       If both PKT and FKT are given, the function returns the foreign key, if
3284       any, in table FKT that refers to the primary (unique) key of table PKT.
3285       (Note: In SQL/CLI, the result is implementation-defined.)
3286
3287       If only PKT is given, then the result set contains the primary key of
3288       that table and all foreign keys that refer to it.
3289
3290       If only FKT is given, then the result set contains all foreign keys in
3291       that table and the primary keys to which they refer.  (Note: In
3292       SQL/CLI, the result includes unique keys too.)
3293
3294       For example:
3295
3296         $sth = $dbh->foreign_key_info( undef, $user, 'master');
3297         $sth = $dbh->foreign_key_info( undef, undef,   undef , undef, $user, 'detail');
3298         $sth = $dbh->foreign_key_info( undef, $user, 'master', undef, $user, 'detail');
3299
3300         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3301
3302       Note: The support for the selection criteria, such as $catalog, is
3303       driver specific.  If the driver doesn't support catalogs and/or
3304       schemas, it may ignore these criteria.
3305
3306       The statement handle returned has the following fields in the order
3307       shown below.  Because ODBC never includes unique keys, they define
3308       different columns in the result set than SQL/CLI. SQL/CLI column names
3309       are shown in parentheses.
3310
3311       PKTABLE_CAT    ( UK_TABLE_CAT      ): The primary (unique) key table
3312       catalog identifier.  This field is NULL ("undef") if not applicable to
3313       the data source, which is often the case.  This field is empty if not
3314       applicable to the table.
3315
3316       PKTABLE_SCHEM  ( UK_TABLE_SCHEM    ): The primary (unique) key table
3317       schema identifier.  This field is NULL ("undef") if not applicable to
3318       the data source, and empty if not applicable to the table.
3319
3320       PKTABLE_NAME   ( UK_TABLE_NAME     ): The primary (unique) key table
3321       identifier.
3322
3323       PKCOLUMN_NAME  (UK_COLUMN_NAME    ): The primary (unique) key column
3324       identifier.
3325
3326       FKTABLE_CAT    ( FK_TABLE_CAT      ): The foreign key table catalog
3327       identifier.  This field is NULL ("undef") if not applicable to the data
3328       source, which is often the case.  This field is empty if not applicable
3329       to the table.
3330
3331       FKTABLE_SCHEM  ( FK_TABLE_SCHEM    ): The foreign key table schema
3332       identifier.  This field is NULL ("undef") if not applicable to the data
3333       source, and empty if not applicable to the table.
3334
3335       FKTABLE_NAME   ( FK_TABLE_NAME     ): The foreign key table identifier.
3336
3337       FKCOLUMN_NAME  ( FK_COLUMN_NAME    ): The foreign key column
3338       identifier.
3339
3340       KEY_SEQ        ( ORDINAL_POSITION  ): The column sequence number
3341       (starting with 1).
3342
3343       UPDATE_RULE    ( UPDATE_RULE       ): The referential action for the
3344       UPDATE rule.  The following codes are defined:
3345
3346         CASCADE              0
3347         RESTRICT             1
3348         SET NULL             2
3349         NO ACTION            3
3350         SET DEFAULT          4
3351
3352       DELETE_RULE    ( DELETE_RULE       ): The referential action for the
3353       DELETE rule.  The codes are the same as for UPDATE_RULE.
3354
3355       FK_NAME        ( FK_NAME           ): The foreign key name.
3356
3357       PK_NAME        ( UK_NAME           ): The primary (unique) key name.
3358
3359       DEFERRABILITY  ( DEFERABILITY      ): The deferrability of the foreign
3360       key constraint.  The following codes are defined:
3361
3362         INITIALLY DEFERRED   5
3363         INITIALLY IMMEDIATE  6
3364         NOT DEFERRABLE       7
3365
3366                      ( UNIQUE_OR_PRIMARY ): This column is necessary if a
3367       driver includes all candidate (i.e. primary and alternate) keys in the
3368       result set (as specified by SQL/CLI).  The value of this column is
3369       UNIQUE if the foreign key references an alternate key and PRIMARY if
3370       the foreign key references a primary key, or it may be undefined if the
3371       driver doesn't have access to the information.
3372
3373       See also "Catalog Methods" and "Standards Reference Information".
3374
3375       "statistics_info"
3376
3377       Warning: This method is experimental and may change.
3378
3379         $sth = $dbh->statistics_info( $catalog, $schema, $table, $unique_only, $quick );
3380
3381         # then $sth->fetchall_arrayref or $sth->fetchall_hashref etc
3382
3383       Returns an active statement handle that can be used to fetch
3384       statistical information about a table and its indexes.
3385
3386       The arguments don't accept search patterns (unlike "table_info").
3387
3388       If the boolean argument $unique_only is true, only UNIQUE indexes will
3389       be returned in the result set, otherwise all indexes will be returned.
3390
3391       If the boolean argument $quick is set, the actual statistical
3392       information columns (CARDINALITY and PAGES) will only be returned if
3393       they are readily available from the server, and might not be current.
3394       Some databases may return stale statistics or no statistics at all with
3395       this flag set.
3396
3397       The statement handle will return at most one row per column name per
3398       index, plus at most one row for the entire table itself, ordered by
3399       NON_UNIQUE, TYPE, INDEX_QUALIFIER, INDEX_NAME, and ORDINAL_POSITION.
3400
3401       Note: The support for the selection criteria, such as $catalog, is
3402       driver specific.  If the driver doesn't support catalogs and/or
3403       schemas, it may ignore these criteria.
3404
3405       The statement handle returned has at least the following fields in the
3406       order shown below. Other fields, after these, may also be present.
3407
3408       TABLE_CAT: The catalog identifier.  This field is NULL ("undef") if not
3409       applicable to the data source, which is often the case.  This field is
3410       empty if not applicable to the table.
3411
3412       TABLE_SCHEM: The schema identifier.  This field is NULL ("undef") if
3413       not applicable to the data source, and empty if not applicable to the
3414       table.
3415
3416       TABLE_NAME: The table identifier.
3417
3418       NON_UNIQUE: Unique index indicator.  Returns 0 for unique indexes, 1
3419       for non-unique indexes
3420
3421       INDEX_QUALIFIER: Index qualifier identifier.  The identifier that is
3422       used to qualify the index name when doing a "DROP INDEX"; NULL
3423       ("undef") is returned if an index qualifier is not supported by the
3424       data source.  If a non-NULL (defined) value is returned in this column,
3425       it must be used to qualify the index name on a "DROP INDEX" statement;
3426       otherwise, the TABLE_SCHEM should be used to qualify the index name.
3427
3428       INDEX_NAME: The index identifier.
3429
3430       TYPE: The type of information being returned.  Can be any of the
3431       following values: 'table', 'btree', 'clustered', 'content', 'hashed',
3432       or 'other'.
3433
3434       In the case that this field is 'table', all fields other than
3435       TABLE_CAT, TABLE_SCHEM, TABLE_NAME, TYPE, CARDINALITY, and PAGES will
3436       be NULL ("undef").
3437
3438       ORDINAL_POSITION: Column sequence number (starting with 1).
3439
3440       COLUMN_NAME: The column identifier.
3441
3442       ASC_OR_DESC: Column sort sequence.  "A" for Ascending, "D" for
3443       Descending, or NULL ("undef") if not supported for this index.
3444
3445       CARDINALITY: Cardinality of the table or index.  For indexes, this is
3446       the number of unique values in the index.  For tables, this is the
3447       number of rows in the table.  If not supported, the value will be NULL
3448       ("undef").
3449
3450       PAGES: Number of storage pages used by this table or index.  If not
3451       supported, the value will be NULL ("undef").
3452
3453       FILTER_CONDITION: The index filter condition as a string.  If the index
3454       is not a filtered index, or it cannot be determined whether the index
3455       is a filtered index, this value is NULL ("undef").  If the index is a
3456       filtered index, but the filter condition cannot be determined, this
3457       value is the empty string ''.  Otherwise it will be the literal filter
3458       condition as a string, such as "SALARY <= 4500".
3459
3460       See also "Catalog Methods" and "Standards Reference Information".
3461
3462       "tables"
3463
3464         @names = $dbh->tables( $catalog, $schema, $table, $type );
3465         @names = $dbh->tables;        # deprecated
3466
3467       Simple interface to table_info(). Returns a list of matching table
3468       names, possibly including a catalog/schema prefix.
3469
3470       See "table_info" for a description of the parameters.
3471
3472       If "$dbh->get_info(29)" returns true (29 is SQL_IDENTIFIER_QUOTE_CHAR)
3473       then the table names are constructed and quoted by "quote_identifier"
3474       to ensure they are usable even if they contain whitespace or reserved
3475       words etc. This means that the table names returned will include quote
3476       characters.
3477
3478       "type_info_all"
3479
3480         $type_info_all = $dbh->type_info_all;
3481
3482       Returns a reference to an array which holds information about each data
3483       type variant supported by the database and driver. The array and its
3484       contents should be treated as read-only.
3485
3486       The first item is a reference to an 'index' hash of "Name ="> "Index"
3487       pairs.  The items following that are references to arrays, one per
3488       supported data type variant. The leading index hash defines the names
3489       and order of the fields within the arrays that follow it.  For example:
3490
3491         $type_info_all = [
3492           {   TYPE_NAME         => 0,
3493               DATA_TYPE         => 1,
3494               COLUMN_SIZE       => 2,     # was PRECISION originally
3495               LITERAL_PREFIX    => 3,
3496               LITERAL_SUFFIX    => 4,
3497               CREATE_PARAMS     => 5,
3498               NULLABLE          => 6,
3499               CASE_SENSITIVE    => 7,
3500               SEARCHABLE        => 8,
3501               UNSIGNED_ATTRIBUTE=> 9,
3502               FIXED_PREC_SCALE  => 10,    # was MONEY originally
3503               AUTO_UNIQUE_VALUE => 11,    # was AUTO_INCREMENT originally
3504               LOCAL_TYPE_NAME   => 12,
3505               MINIMUM_SCALE     => 13,
3506               MAXIMUM_SCALE     => 14,
3507               SQL_DATA_TYPE     => 15,
3508               SQL_DATETIME_SUB  => 16,
3509               NUM_PREC_RADIX    => 17,
3510               INTERVAL_PRECISION=> 18,
3511           },
3512           [ 'VARCHAR', SQL_VARCHAR,
3513               undef, "'","'", undef,0, 1,1,0,0,0,undef,1,255, undef
3514           ],
3515           [ 'INTEGER', SQL_INTEGER,
3516               undef,  "", "", undef,0, 0,1,0,0,0,undef,0,  0, 10
3517           ],
3518         ];
3519
3520       More than one row may have the same value in the "DATA_TYPE" field if
3521       there are different ways to spell the type name and/or there are
3522       variants of the type with different attributes (e.g., with and without
3523       "AUTO_UNIQUE_VALUE" set, with and without "UNSIGNED_ATTRIBUTE", etc).
3524
3525       The rows are ordered by "DATA_TYPE" first and then by how closely each
3526       type maps to the corresponding ODBC SQL data type, closest first.
3527
3528       The meaning of the fields is described in the documentation for the
3529       "type_info" method.
3530
3531       An 'index' hash is provided so you don't need to rely on index values
3532       defined above.  However, using DBD::ODBC with some old ODBC drivers may
3533       return older names, shown as comments in the example above.  Another
3534       issue with the index hash is that the lettercase of the keys is not
3535       defined. It is usually uppercase, as show here, but drivers may return
3536       names with any lettercase.
3537
3538       Drivers are also free to return extra driver-specific columns of
3539       information - though it's recommended that they start at column index
3540       50 to leave room for expansion of the DBI/ODBC specification.
3541
3542       The type_info_all() method is not normally used directly.  The
3543       "type_info" method provides a more usable and useful interface to the
3544       data.
3545
3546       "type_info"
3547
3548         @type_info = $dbh->type_info($data_type);
3549
3550       Returns a list of hash references holding information about one or more
3551       variants of $data_type. The list is ordered by "DATA_TYPE" first and
3552       then by how closely each type maps to the corresponding ODBC SQL data
3553       type, closest first.  If called in a scalar context then only the first
3554       (best) element is returned.
3555
3556       If $data_type is undefined or "SQL_ALL_TYPES", then the list will
3557       contain hashes for all data type variants supported by the database and
3558       driver.
3559
3560       If $data_type is an array reference then "type_info" returns the
3561       information for the first type in the array that has any matches.
3562
3563       The keys of the hash follow the same letter case conventions as the
3564       rest of the DBI (see "Naming Conventions and Name Space"). The
3565       following uppercase items should always exist, though may be undef:
3566
3567       TYPE_NAME (string)
3568           Data type name for use in CREATE TABLE statements etc.
3569
3570       DATA_TYPE (integer)
3571           SQL data type number.
3572
3573       COLUMN_SIZE (integer)
3574           For numeric types, this is either the total number of digits (if
3575           the NUM_PREC_RADIX value is 10) or the total number of bits allowed
3576           in the column (if NUM_PREC_RADIX is 2).
3577
3578           For string types, this is the maximum size of the string in
3579           characters.
3580
3581           For date and interval types, this is the maximum number of
3582           characters needed to display the value.
3583
3584       LITERAL_PREFIX (string)
3585           Characters used to prefix a literal. A typical prefix is ""'"" for
3586           characters, or possibly ""0x"" for binary values passed as
3587           hexadecimal.  NULL ("undef") is returned for data types for which
3588           this is not applicable.
3589
3590       LITERAL_SUFFIX (string)
3591           Characters used to suffix a literal. Typically ""'"" for
3592           characters.  NULL ("undef") is returned for data types where this
3593           is not applicable.
3594
3595       CREATE_PARAMS (string)
3596           Parameter names for data type definition. For example,
3597           "CREATE_PARAMS" for a "DECIMAL" would be ""precision,scale"" if the
3598           DECIMAL type should be declared as "DECIMAL("precision,scale")"
3599           where precision and scale are integer values.  For a "VARCHAR" it
3600           would be ""max length"".  NULL ("undef") is returned for data types
3601           for which this is not applicable.
3602
3603       NULLABLE (integer)
3604           Indicates whether the data type accepts a NULL value: 0 or an empty
3605           string = no, 1 = yes, 2 = unknown.
3606
3607       CASE_SENSITIVE (boolean)
3608           Indicates whether the data type is case sensitive in collations and
3609           comparisons.
3610
3611       SEARCHABLE (integer)
3612           Indicates how the data type can be used in a WHERE clause, as
3613           follows:
3614
3615             0 - Cannot be used in a WHERE clause
3616             1 - Only with a LIKE predicate
3617             2 - All comparison operators except LIKE
3618             3 - Can be used in a WHERE clause with any comparison operator
3619
3620       UNSIGNED_ATTRIBUTE (boolean)
3621           Indicates whether the data type is unsigned.  NULL ("undef") is
3622           returned for data types for which this is not applicable.
3623
3624       FIXED_PREC_SCALE (boolean)
3625           Indicates whether the data type always has the same precision and
3626           scale (such as a money type).  NULL ("undef") is returned for data
3627           types for which this is not applicable.
3628
3629       AUTO_UNIQUE_VALUE (boolean)
3630           Indicates whether a column of this data type is automatically set
3631           to a unique value whenever a new row is inserted.  NULL ("undef")
3632           is returned for data types for which this is not applicable.
3633
3634       LOCAL_TYPE_NAME (string)
3635           Localized version of the "TYPE_NAME" for use in dialog with users.
3636           NULL ("undef") is returned if a localized name is not available (in
3637           which case "TYPE_NAME" should be used).
3638
3639       MINIMUM_SCALE (integer)
3640           The minimum scale of the data type. If a data type has a fixed
3641           scale, then "MAXIMUM_SCALE" holds the same value.  NULL ("undef")
3642           is returned for data types for which this is not applicable.
3643
3644       MAXIMUM_SCALE (integer)
3645           The maximum scale of the data type. If a data type has a fixed
3646           scale, then "MINIMUM_SCALE" holds the same value.  NULL ("undef")
3647           is returned for data types for which this is not applicable.
3648
3649       SQL_DATA_TYPE (integer)
3650           This column is the same as the "DATA_TYPE" column, except for
3651           interval and datetime data types.  For interval and datetime data
3652           types, the "SQL_DATA_TYPE" field will return "SQL_INTERVAL" or
3653           "SQL_DATETIME", and the "SQL_DATETIME_SUB" field below will return
3654           the subcode for the specific interval or datetime data type. If
3655           this field is NULL, then the driver does not support or report on
3656           interval or datetime subtypes.
3657
3658       SQL_DATETIME_SUB (integer)
3659           For interval or datetime data types, where the "SQL_DATA_TYPE"
3660           field above is "SQL_INTERVAL" or "SQL_DATETIME", this field will
3661           hold the subcode for the specific interval or datetime data type.
3662           Otherwise it will be NULL ("undef").
3663
3664           Although not mentioned explicitly in the standards, it seems there
3665           is a simple relationship between these values:
3666
3667             DATA_TYPE == (10 * SQL_DATA_TYPE) + SQL_DATETIME_SUB
3668
3669       NUM_PREC_RADIX (integer)
3670           The radix value of the data type. For approximate numeric types,
3671           "NUM_PREC_RADIX" contains the value 2 and "COLUMN_SIZE" holds the
3672           number of bits. For exact numeric types, "NUM_PREC_RADIX" contains
3673           the value 10 and "COLUMN_SIZE" holds the number of decimal digits.
3674           NULL ("undef") is returned either for data types for which this is
3675           not applicable or if the driver cannot report this information.
3676
3677       INTERVAL_PRECISION (integer)
3678           The interval leading precision for interval types. NULL is returned
3679           either for data types for which this is not applicable or if the
3680           driver cannot report this information.
3681
3682       For example, to find the type name for the fields in a select statement
3683       you can do:
3684
3685         @names = map { scalar $dbh->type_info($_)->{TYPE_NAME} } @{ $sth->{TYPE} }
3686
3687       Since DBI and ODBC drivers vary in how they map their types into the
3688       ISO standard types you may need to search for more than one type.
3689       Here's an example looking for a usable type to store a date:
3690
3691         $my_date_type = $dbh->type_info( [ SQL_DATE, SQL_TIMESTAMP ] );
3692
3693       Similarly, to more reliably find a type to store small integers, you
3694       could use a list starting with "SQL_SMALLINT", "SQL_INTEGER",
3695       "SQL_DECIMAL", etc.
3696
3697       See also "Standards Reference Information".
3698
3699       "quote"
3700
3701         $sql = $dbh->quote($value);
3702         $sql = $dbh->quote($value, $data_type);
3703
3704       Quote a string literal for use as a literal value in an SQL statement,
3705       by escaping any special characters (such as quotation marks) contained
3706       within the string and adding the required type of outer quotation
3707       marks.
3708
3709         $sql = sprintf "SELECT foo FROM bar WHERE baz = %s",
3710                       $dbh->quote("Don't");
3711
3712       For most database types, at least those that conform to SQL standards,
3713       quote would return 'Don''t' (including the outer quotation marks). For
3714       others it may return something like 'Don\'t'
3715
3716       An undefined $value value will be returned as the string "NULL"
3717       (without single quotation marks) to match how NULLs are represented in
3718       SQL.
3719
3720       If $data_type is supplied, it is used to try to determine the required
3721       quoting behaviour by using the information returned by "type_info".  As
3722       a special case, the standard numeric types are optimized to return
3723       $value without calling "type_info".
3724
3725       Quote will probably not be able to deal with all possible input (such
3726       as binary data or data containing newlines), and is not related in any
3727       way with escaping or quoting shell meta-characters.
3728
3729       It is valid for the quote() method to return an SQL expression that
3730       evaluates to the desired string. For example:
3731
3732         $quoted = $dbh->quote("one\ntwo\0three")
3733
3734       may return something like:
3735
3736         CONCAT('one', CHAR(12), 'two', CHAR(0), 'three')
3737
3738       The quote() method should not be used with "Placeholders and Bind
3739       Values".
3740
3741       "quote_identifier"
3742
3743         $sql = $dbh->quote_identifier( $name );
3744         $sql = $dbh->quote_identifier( $catalog, $schema, $table, \%attr );
3745
3746       Quote an identifier (table name etc.) for use in an SQL statement, by
3747       escaping any special characters (such as double quotation marks) it
3748       contains and adding the required type of outer quotation marks.
3749
3750       Undefined names are ignored and the remainder are quoted and then
3751       joined together, typically with a dot (".") character. For example:
3752
3753         $id = $dbh->quote_identifier( undef, 'Her schema', 'My table' );
3754
3755       would, for most database types, return "Her schema"."My table"
3756       (including all the double quotation marks).
3757
3758       If three names are supplied then the first is assumed to be a catalog
3759       name and special rules may be applied based on what "get_info" returns
3760       for SQL_CATALOG_NAME_SEPARATOR (41) and SQL_CATALOG_LOCATION (114).
3761       For example, for Oracle:
3762
3763         $id = $dbh->quote_identifier( 'link', 'schema', 'table' );
3764
3765       would return "schema"."table"@"link".
3766
3767       "take_imp_data"
3768
3769         $imp_data = $dbh->take_imp_data;
3770
3771       Leaves the $dbh in an almost dead, zombie-like, state and returns a
3772       binary string of raw implementation data from the driver which
3773       describes the current database connection. Effectively it detaches the
3774       underlying database API connection data from the DBI handle.  After
3775       calling take_imp_data(), all other methods except "DESTROY" will
3776       generate a warning and return undef.
3777
3778       Why would you want to do this? You don't, forget I even mentioned it.
3779       Unless, that is, you're implementing something advanced like a multi-
3780       threaded connection pool. See DBI::Pool.
3781
3782       The returned $imp_data can be passed as a "dbi_imp_data" attribute to a
3783       later connect() call, even in a separate thread in the same process,
3784       where the driver can use it to 'adopt' the existing connection that the
3785       implementation data was taken from.
3786
3787       Some things to keep in mind...
3788
3789       * the $imp_data holds the only reference to the underlying database API
3790       connection data. That connection is still 'live' and won't be cleaned
3791       up properly unless the $imp_data is used to create a new $dbh which is
3792       then allowed to disconnect() normally.
3793
3794       * using the same $imp_data to create more than one other new $dbh at a
3795       time may well lead to unpleasant problems. Don't do that.
3796
3797       Any child statement handles are effectively destroyed when
3798       take_imp_data() is called.
3799
3800       The "take_imp_data" method was added in DBI 1.36 but wasn't useful till
3801       1.49.
3802
3803   Database Handle Attributes
3804       This section describes attributes specific to database handles.
3805
3806       Changes to these database handle attributes do not affect any other
3807       existing or future database handles.
3808
3809       Attempting to set or get the value of an unknown attribute generates a
3810       warning, except for private driver-specific attributes (which all have
3811       names starting with a lowercase letter).
3812
3813       Example:
3814
3815         $h->{AutoCommit} = ...;       # set/write
3816         ... = $h->{AutoCommit};       # get/read
3817
3818       "AutoCommit"
3819
3820       Type: boolean
3821
3822       If true, then database changes cannot be rolled-back (undone).  If
3823       false, then database changes automatically occur within a
3824       "transaction", which must either be committed or rolled back using the
3825       "commit" or "rollback" methods.
3826
3827       Drivers should always default to "AutoCommit" mode (an unfortunate
3828       choice largely forced on the DBI by ODBC and JDBC conventions.)
3829
3830       Attempting to set "AutoCommit" to an unsupported value is a fatal
3831       error.  This is an important feature of the DBI. Applications that need
3832       full transaction behaviour can set "$dbh->{AutoCommit} = 0" (or set
3833       "AutoCommit" to 0 via "connect") without having to check that the value
3834       was assigned successfully.
3835
3836       For the purposes of this description, we can divide databases into
3837       three categories:
3838
3839         Databases which don't support transactions at all.
3840         Databases in which a transaction is always active.
3841         Databases in which a transaction must be explicitly started (C<'BEGIN WORK'>).
3842
3843       * Databases which don't support transactions at all
3844
3845       For these databases, attempting to turn "AutoCommit" off is a fatal
3846       error.  "commit" and "rollback" both issue warnings about being
3847       ineffective while "AutoCommit" is in effect.
3848
3849       * Databases in which a transaction is always active
3850
3851       These are typically mainstream commercial relational databases with
3852       "ANSI standard" transaction behaviour.  If "AutoCommit" is off, then
3853       changes to the database won't have any lasting effect unless "commit"
3854       is called (but see also "disconnect"). If "rollback" is called then any
3855       changes since the last commit are undone.
3856
3857       If "AutoCommit" is on, then the effect is the same as if the DBI called
3858       "commit" automatically after every successful database operation. So
3859       calling "commit" or "rollback" explicitly while "AutoCommit" is on
3860       would be ineffective because the changes would have already been
3861       committed.
3862
3863       Changing "AutoCommit" from off to on will trigger a "commit".
3864
3865       For databases which don't support a specific auto-commit mode, the
3866       driver has to commit each statement automatically using an explicit
3867       "COMMIT" after it completes successfully (and roll it back using an
3868       explicit "ROLLBACK" if it fails).  The error information reported to
3869       the application will correspond to the statement which was executed,
3870       unless it succeeded and the commit or rollback failed.
3871
3872       * Databases in which a transaction must be explicitly started
3873
3874       For these databases, the intention is to have them act like databases
3875       in which a transaction is always active (as described above).
3876
3877       To do this, the driver will automatically begin an explicit transaction
3878       when "AutoCommit" is turned off, or after a "commit" or "rollback" (or
3879       when the application issues the next database operation after one of
3880       those events).
3881
3882       In this way, the application does not have to treat these databases as
3883       a special case.
3884
3885       See "commit", "disconnect" and "Transactions" for other important notes
3886       about transactions.
3887
3888       "Driver"
3889
3890       Type: handle
3891
3892       Holds the handle of the parent driver. The only recommended use for
3893       this is to find the name of the driver using:
3894
3895         $dbh->{Driver}->{Name}
3896
3897       "Name"
3898
3899       Type: string
3900
3901       Holds the "name" of the database. Usually (and recommended to be) the
3902       same as the ""dbi:DriverName:..."" string used to connect to the
3903       database, but with the leading ""dbi:DriverName:"" removed.
3904
3905       "Statement"
3906
3907       Type: string, read-only
3908
3909       Returns the statement string passed to the most recent "prepare" or
3910       "do" method called in this database handle, even if that method failed.
3911       This is especially useful where "RaiseError" is enabled and the
3912       exception handler checks $@ and sees that a 'prepare' method call
3913       failed.
3914
3915       "RowCacheSize"
3916
3917       Type: integer
3918
3919       A hint to the driver indicating the size of the local row cache that
3920       the application would like the driver to use for future "SELECT"
3921       statements.  If a row cache is not implemented, then setting
3922       "RowCacheSize" is ignored and getting the value returns "undef".
3923
3924       Some "RowCacheSize" values have special meaning, as follows:
3925
3926         0 - Automatically determine a reasonable cache size for each C<SELECT>
3927         1 - Disable the local row cache
3928        >1 - Cache this many rows
3929        <0 - Cache as many rows that will fit into this much memory for each C<SELECT>.
3930
3931       Note that large cache sizes may require a very large amount of memory
3932       (cached rows * maximum size of row). Also, a large cache will cause a
3933       longer delay not only for the first fetch, but also whenever the cache
3934       needs refilling.
3935
3936       See also the "RowsInCache" statement handle attribute.
3937
3938       "Username"
3939
3940       Type: string
3941
3942       Returns the username used to connect to the database.
3943

DBI STATEMENT HANDLE OBJECTS

3945       This section lists the methods and attributes associated with DBI
3946       statement handles.
3947
3948   Statement Handle Methods
3949       The DBI defines the following methods for use on DBI statement handles:
3950
3951       "bind_param"
3952
3953         $sth->bind_param($p_num, $bind_value)
3954         $sth->bind_param($p_num, $bind_value, \%attr)
3955         $sth->bind_param($p_num, $bind_value, $bind_type)
3956
3957       The "bind_param" method takes a copy of $bind_value and associates it
3958       (binds it) with a placeholder, identified by $p_num, embedded in the
3959       prepared statement. Placeholders are indicated with question mark
3960       character ("?"). For example:
3961
3962         $dbh->{RaiseError} = 1;        # save having to check each method call
3963         $sth = $dbh->prepare("SELECT name, age FROM people WHERE name LIKE ?");
3964         $sth->bind_param(1, "John%");  # placeholders are numbered from 1
3965         $sth->execute;
3966         DBI::dump_results($sth);
3967
3968       See "Placeholders and Bind Values" for more information.
3969
3970       Data Types for Placeholders
3971
3972       The "\%attr" parameter can be used to hint at the data type the
3973       placeholder should have. This is rarely needed. Typically, the driver
3974       is only interested in knowing if the placeholder should be bound as a
3975       number or a string.
3976
3977         $sth->bind_param(1, $value, { TYPE => SQL_INTEGER });
3978
3979       As a short-cut for the common case, the data type can be passed
3980       directly, in place of the "\%attr" hash reference. This example is
3981       equivalent to the one above:
3982
3983         $sth->bind_param(1, $value, SQL_INTEGER);
3984
3985       The "TYPE" value indicates the standard (non-driver-specific) type for
3986       this parameter. To specify the driver-specific type, the driver may
3987       support a driver-specific attribute, such as "{ ora_type => 97 }".
3988
3989       The SQL_INTEGER and other related constants can be imported using
3990
3991         use DBI qw(:sql_types);
3992
3993       See "DBI Constants" for more information.
3994
3995       The data type is 'sticky' in that bind values passed to execute() are
3996       bound with the data type specified by earlier bind_param() calls, if
3997       any.  Portable applications should not rely on being able to change the
3998       data type after the first "bind_param" call.
3999
4000       Perl only has string and number scalar data types. All database types
4001       that aren't numbers are bound as strings and must be in a format the
4002       database will understand except where the bind_param() TYPE attribute
4003       specifies a type that implies a particular format. For example, given:
4004
4005         $sth->bind_param(1, $value, SQL_DATETIME);
4006
4007       the driver should expect $value to be in the ODBC standard SQL_DATETIME
4008       format, which is 'YYYY-MM-DD HH:MM:SS'. Similarly for SQL_DATE,
4009       SQL_TIME etc.
4010
4011       As an alternative to specifying the data type in the "bind_param" call,
4012       you can let the driver pass the value as the default type ("VARCHAR").
4013       You can then use an SQL function to convert the type within the
4014       statement.  For example:
4015
4016         INSERT INTO price(code, price) VALUES (?, CONVERT(MONEY,?))
4017
4018       The "CONVERT" function used here is just an example. The actual
4019       function and syntax will vary between different databases and is non-
4020       portable.
4021
4022       See also "Placeholders and Bind Values" for more information.
4023
4024       "bind_param_inout"
4025
4026         $rc = $sth->bind_param_inout($p_num, \$bind_value, $max_len)  or die $sth->errstr;
4027         $rv = $sth->bind_param_inout($p_num, \$bind_value, $max_len, \%attr)     or ...
4028         $rv = $sth->bind_param_inout($p_num, \$bind_value, $max_len, $bind_type) or ...
4029
4030       This method acts like "bind_param", but also enables values to be
4031       updated by the statement. The statement is typically a call to a stored
4032       procedure. The $bind_value must be passed as a reference to the actual
4033       value to be used.
4034
4035       Note that unlike "bind_param", the $bind_value variable is not copied
4036       when "bind_param_inout" is called. Instead, the value in the variable
4037       is read at the time "execute" is called.
4038
4039       The additional $max_len parameter specifies the minimum amount of
4040       memory to allocate to $bind_value for the new value. If the value
4041       returned from the database is too big to fit, then the execution should
4042       fail. If unsure what value to use, pick a generous length, i.e., a
4043       length larger than the longest value that would ever be returned.  The
4044       only cost of using a larger value than needed is wasted memory.
4045
4046       Undefined values or "undef" are used to indicate null values.  See also
4047       "Placeholders and Bind Values" for more information.
4048
4049       "bind_param_array"
4050
4051         $rc = $sth->bind_param_array($p_num, $array_ref_or_value)
4052         $rc = $sth->bind_param_array($p_num, $array_ref_or_value, \%attr)
4053         $rc = $sth->bind_param_array($p_num, $array_ref_or_value, $bind_type)
4054
4055       The "bind_param_array" method is used to bind an array of values to a
4056       placeholder embedded in the prepared statement which is to be executed
4057       with "execute_array". For example:
4058
4059         $dbh->{RaiseError} = 1;        # save having to check each method call
4060         $sth = $dbh->prepare("INSERT INTO staff (first_name, last_name, dept) VALUES(?, ?, ?)");
4061         $sth->bind_param_array(1, [ 'John', 'Mary', 'Tim' ]);
4062         $sth->bind_param_array(2, [ 'Booth', 'Todd', 'Robinson' ]);
4063         $sth->bind_param_array(3, "SALES"); # scalar will be reused for each row
4064         $sth->execute_array( { ArrayTupleStatus => \my @tuple_status } );
4065
4066       The %attr ($bind_type) argument is the same as defined for
4067       "bind_param".  Refer to "bind_param" for general details on using
4068       placeholders.
4069
4070       (Note that bind_param_array() can not be used to expand a placeholder
4071       into a list of values for a statement like "SELECT foo WHERE bar IN
4072       (?)".  A placeholder can only ever represent one value per execution.)
4073
4074       Scalar values, including "undef", may also be bound by
4075       "bind_param_array". In which case the same value will be used for each
4076       "execute" call. Driver-specific implementations may behave differently,
4077       e.g., when binding to a stored procedure call, some databases may
4078       permit mixing scalars and arrays as arguments.
4079
4080       The default implementation provided by DBI (for drivers that have not
4081       implemented array binding) is to iteratively call "execute" for each
4082       parameter tuple provided in the bound arrays.  Drivers may provide more
4083       optimized implementations using whatever bulk operation support the
4084       database API provides. The default driver behaviour should match the
4085       default DBI behaviour, but always consult your driver documentation as
4086       there may be driver specific issues to consider.
4087
4088       Note that the default implementation currently only supports non-data
4089       returning statements (INSERT, UPDATE, but not SELECT). Also,
4090       "bind_param_array" and "bind_param" cannot be mixed in the same
4091       statement execution, and "bind_param_array" must be used with
4092       "execute_array"; using "bind_param_array" will have no effect for
4093       "execute".
4094
4095       The "bind_param_array" method was added in DBI 1.22.
4096
4097       "execute"
4098
4099         $rv = $sth->execute                or die $sth->errstr;
4100         $rv = $sth->execute(@bind_values)  or die $sth->errstr;
4101
4102       Perform whatever processing is necessary to execute the prepared
4103       statement.  An "undef" is returned if an error occurs.  A successful
4104       "execute" always returns true regardless of the number of rows
4105       affected, even if it's zero (see below). It is always important to
4106       check the return status of "execute" (and most other DBI methods) for
4107       errors if you're not using "RaiseError".
4108
4109       For a non-"SELECT" statement, "execute" returns the number of rows
4110       affected, if known. If no rows were affected, then "execute" returns
4111       "0E0", which Perl will treat as 0 but will regard as true. Note that it
4112       is not an error for no rows to be affected by a statement. If the
4113       number of rows affected is not known, then "execute" returns -1.
4114
4115       For "SELECT" statements, execute simply "starts" the query within the
4116       database engine. Use one of the fetch methods to retrieve the data
4117       after calling "execute".  The "execute" method does not return the
4118       number of rows that will be returned by the query (because most
4119       databases can't tell in advance), it simply returns a true value.
4120
4121       You can tell if the statement was a "SELECT" statement by checking if
4122       "$sth->{NUM_OF_FIELDS}" is greater than zero after calling "execute".
4123
4124       If any arguments are given, then "execute" will effectively call
4125       "bind_param" for each value before executing the statement.  Values
4126       bound in this way are usually treated as "SQL_VARCHAR" types unless the
4127       driver can determine the correct type (which is rare), or unless
4128       "bind_param" (or "bind_param_inout") has already been used to specify
4129       the type.
4130
4131       Note that passing "execute" an empty array is the same as passing no
4132       arguments at all, which will execute the statement with previously
4133       bound values.  That's probably not what you want.
4134
4135       If execute() is called on a statement handle that's still active
4136       ($sth->{Active} is true) then it should effectively call finish() to
4137       tidy up the previous execution results before starting this new
4138       execution.
4139
4140       "execute_array"
4141
4142         $tuples = $sth->execute_array(\%attr) or die $sth->errstr;
4143         $tuples = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;
4144
4145         ($tuples, $rows) = $sth->execute_array(\%attr) or die $sth->errstr;
4146         ($tuples, $rows) = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;
4147
4148       Execute the prepared statement once for each parameter tuple (group of
4149       values) provided either in the @bind_values, or by prior calls to
4150       "bind_param_array", or via a reference passed in \%attr.
4151
4152       When called in scalar context the execute_array() method returns the
4153       number of tuples executed, or "undef" if an error occurred.  Like
4154       execute(), a successful execute_array() always returns true regardless
4155       of the number of tuples executed, even if it's zero. If there were any
4156       errors the ArrayTupleStatus array can be used to discover which tuples
4157       failed and with what errors.
4158
4159       When called in list context the execute_array() method returns two
4160       scalars; $tuples is the same as calling execute_array() in scalar
4161       context and $rows is the number of rows affected for each tuple, if
4162       available or -1 if the driver cannot determine this. NOTE, some drivers
4163       cannot determine the number of rows affected per tuple but can provide
4164       the number of rows affected for the batch.  If you are doing an update
4165       operation the returned rows affected may not be what you expect if, for
4166       instance, one or more of the tuples affected the same row multiple
4167       times.  Some drivers may not yet support list context, in which case
4168       $rows will be undef, or may not be able to provide the number of rows
4169       affected when performing this batch operation, in which case $rows will
4170       be -1.
4171
4172       Bind values for the tuples to be executed may be supplied row-wise by
4173       an "ArrayTupleFetch" attribute, or else column-wise in the @bind_values
4174       argument, or else column-wise by prior calls to "bind_param_array".
4175
4176       Where column-wise binding is used (via the @bind_values argument or
4177       calls to bind_param_array()) the maximum number of elements in any one
4178       of the bound value arrays determines the number of tuples executed.
4179       Placeholders with fewer values in their parameter arrays are treated as
4180       if padded with undef (NULL) values.
4181
4182       If a scalar value is bound, instead of an array reference, it is
4183       treated as a variable length array with all elements having the same
4184       value. It does not influence the number of tuples executed, so if all
4185       bound arrays have zero elements then zero tuples will be executed. If
4186       all bound values are scalars then one tuple will be executed, making
4187       execute_array() act just like execute().
4188
4189       The "ArrayTupleFetch" attribute can be used to specify a reference to a
4190       subroutine that will be called to provide the bind values for each
4191       tuple execution. The subroutine should return an reference to an array
4192       which contains the appropriate number of bind values, or return an
4193       undef if there is no more data to execute.
4194
4195       As a convenience, the "ArrayTupleFetch" attribute can also be used to
4196       specify a statement handle. In which case the fetchrow_arrayref()
4197       method will be called on the given statement handle in order to provide
4198       the bind values for each tuple execution.
4199
4200       The values specified via bind_param_array() or the @bind_values
4201       parameter may be either scalars, or arrayrefs.  If any @bind_values are
4202       given, then "execute_array" will effectively call "bind_param_array"
4203       for each value before executing the statement.  Values bound in this
4204       way are usually treated as "SQL_VARCHAR" types unless the driver can
4205       determine the correct type (which is rare), or unless "bind_param",
4206       "bind_param_inout", "bind_param_array", or "bind_param_inout_array" has
4207       already been used to specify the type.  See "bind_param_array" for
4208       details.
4209
4210       The "ArrayTupleStatus" attribute can be used to specify a reference to
4211       an array which will receive the execute status of each executed
4212       parameter tuple. Note the "ArrayTupleStatus" attribute was mandatory
4213       until DBI 1.38.
4214
4215       For tuples which are successfully executed, the element at the same
4216       ordinal position in the status array is the resulting rowcount (or -1
4217       if unknown).  If the execution of a tuple causes an error, then the
4218       corresponding status array element will be set to a reference to an
4219       array containing "err", "errstr" and "state" set by the failed
4220       execution.
4221
4222       If any tuple execution returns an error, "execute_array" will return
4223       "undef". In that case, the application should inspect the status array
4224       to determine which parameter tuples failed.  Some databases may not
4225       continue executing tuples beyond the first failure. In this case the
4226       status array will either hold fewer elements, or the elements beyond
4227       the failure will be undef.
4228
4229       If all parameter tuples are successfully executed, "execute_array"
4230       returns the number tuples executed.  If no tuples were executed, then
4231       execute_array() returns "0E0", just like execute() does, which Perl
4232       will treat as 0 but will regard as true.
4233
4234       For example:
4235
4236         $sth = $dbh->prepare("INSERT INTO staff (first_name, last_name) VALUES (?, ?)");
4237         my $tuples = $sth->execute_array(
4238             { ArrayTupleStatus => \my @tuple_status },
4239             \@first_names,
4240             \@last_names,
4241         );
4242         if ($tuples) {
4243             print "Successfully inserted $tuples records\n";
4244         }
4245         else {
4246             for my $tuple (0..@last_names-1) {
4247                 my $status = $tuple_status[$tuple];
4248                 $status = [0, "Skipped"] unless defined $status;
4249                 next unless ref $status;
4250                 printf "Failed to insert (%s, %s): %s\n",
4251                     $first_names[$tuple], $last_names[$tuple], $status->[1];
4252             }
4253         }
4254
4255       Support for data returning statements such as SELECT is driver-specific
4256       and subject to change. At present, the default implementation provided
4257       by DBI only supports non-data returning statements.
4258
4259       Transaction semantics when using array binding are driver and database
4260       specific.  If "AutoCommit" is on, the default DBI implementation will
4261       cause each parameter tuple to be individually committed (or rolled back
4262       in the event of an error). If "AutoCommit" is off, the application is
4263       responsible for explicitly committing the entire set of bound parameter
4264       tuples.  Note that different drivers and databases may have different
4265       behaviours when some parameter tuples cause failures. In some cases,
4266       the driver or database may automatically rollback the effect of all
4267       prior parameter tuples that succeeded in the transaction; other drivers
4268       or databases may retain the effect of prior successfully executed
4269       parameter tuples. Be sure to check your driver and database for its
4270       specific behaviour.
4271
4272       Note that, in general, performance will usually be better with
4273       "AutoCommit" turned off, and using explicit "commit" after each
4274       "execute_array" call.
4275
4276       The "execute_array" method was added in DBI 1.22, and ArrayTupleFetch
4277       was added in 1.36.
4278
4279       "execute_for_fetch"
4280
4281         $tuples = $sth->execute_for_fetch($fetch_tuple_sub);
4282         $tuples = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);
4283
4284         ($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub);
4285         ($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);
4286
4287       The execute_for_fetch() method is used to perform bulk operations and
4288       although it is most often used via the execute_array() method you can
4289       use it directly. The main difference between execute_array and
4290       execute_for_fetch is the former does column or row-wise binding and the
4291       latter uses row-wise binding.
4292
4293       The fetch subroutine, referenced by $fetch_tuple_sub, is expected to
4294       return a reference to an array (known as a 'tuple') or undef.
4295
4296       The execute_for_fetch() method calls $fetch_tuple_sub, without any
4297       parameters, until it returns a false value. Each tuple returned is used
4298       to provide bind values for an $sth->execute(@$tuple) call.
4299
4300       In scalar context execute_for_fetch() returns "undef" if there were any
4301       errors and the number of tuples executed otherwise. Like execute() and
4302       execute_array() a zero is returned as "0E0" so execute_for_fetch() is
4303       only false on error.  If there were any errors the @tuple_status array
4304       can be used to discover which tuples failed and with what errors.
4305
4306       When called in list context execute_for_fetch() returns two scalars;
4307       $tuples is the same as calling execute_for_fetch() in scalar context
4308       and $rows is the sum of the number of rows affected for each tuple, if
4309       available or -1 if the driver cannot determine this.  If you are doing
4310       an update operation the returned rows affected may not be what you
4311       expect if, for instance, one or more of the tuples affected the same
4312       row multiple times.  Some drivers may not yet support list context, in
4313       which case $rows will be undef, or may not be able to provide the
4314       number of rows affected when performing this batch operation, in which
4315       case $rows will be -1.
4316
4317       If \@tuple_status is passed then the execute_for_fetch method uses it
4318       to return status information. The tuple_status array holds one element
4319       per tuple. If the corresponding execute() did not fail then the element
4320       holds the return value from execute(), which is typically a row count.
4321       If the execute() did fail then the element holds a reference to an
4322       array containing ($sth->err, $sth->errstr, $sth->state).
4323
4324       If the driver detects an error that it knows means no further tuples
4325       can be executed then it may return, with an error status, even though
4326       $fetch_tuple_sub may still have more tuples to be executed.
4327
4328       Although each tuple returned by $fetch_tuple_sub is effectively used to
4329       call $sth->execute(@$tuple_array_ref) the exact timing may vary.
4330       Drivers are free to accumulate sets of tuples to pass to the database
4331       server in bulk group operations for more efficient execution.  However,
4332       the $fetch_tuple_sub is specifically allowed to return the same array
4333       reference each time (which is what fetchrow_arrayref() usually does).
4334
4335       For example:
4336
4337         my $sel = $dbh1->prepare("select foo, bar from table1");
4338         $sel->execute;
4339
4340         my $ins = $dbh2->prepare("insert into table2 (foo, bar) values (?,?)");
4341         my $fetch_tuple_sub = sub { $sel->fetchrow_arrayref };
4342
4343         my @tuple_status;
4344         $rc = $ins->execute_for_fetch($fetch_tuple_sub, \@tuple_status);
4345         my @errors = grep { ref $_ } @tuple_status;
4346
4347       Similarly, if you already have an array containing the data rows to be
4348       processed you'd use a subroutine to shift off and return each array ref
4349       in turn:
4350
4351         $ins->execute_for_fetch( sub { shift @array_of_arrays }, \@tuple_status);
4352
4353       The "execute_for_fetch" method was added in DBI 1.38.
4354
4355       "last_insert_id"
4356
4357         $rv = $sth->last_insert_id();
4358         $rv = $sth->last_insert_id($catalog, $schema, $table, $field);
4359         $rv = $sth->last_insert_id($catalog, $schema, $table, $field, \%attr);
4360
4361       Returns a value 'identifying' the row inserted by last execution of the
4362       statement $sth, if possible.
4363
4364       For some drivers the value may be 'identifying' the row inserted by the
4365       last executed statement, not by $sth.
4366
4367       See database handle method last_insert_id for all details.
4368
4369       The "last_insert_id" statement method was added in DBI 1.642.
4370
4371       "fetchrow_arrayref"
4372
4373         $ary_ref = $sth->fetchrow_arrayref;
4374         $ary_ref = $sth->fetch;    # alias
4375
4376       Fetches the next row of data and returns a reference to an array
4377       holding the field values.  Null fields are returned as "undef" values
4378       in the array.  This is the fastest way to fetch data, particularly if
4379       used with "$sth->bind_columns".
4380
4381       If there are no more rows or if an error occurs, then
4382       "fetchrow_arrayref" returns an "undef". You should check "$sth->err"
4383       afterwards (or use the "RaiseError" attribute) to discover if the
4384       "undef" returned was due to an error.
4385
4386       Note that the same array reference is returned for each fetch, so don't
4387       store the reference and then use it after a later fetch.  Also, the
4388       elements of the array are also reused for each row, so take care if you
4389       want to take a reference to an element. See also "bind_columns".
4390
4391       "fetchrow_array"
4392
4393        @ary = $sth->fetchrow_array;
4394
4395       An alternative to "fetchrow_arrayref". Fetches the next row of data and
4396       returns it as a list containing the field values.  Null fields are
4397       returned as "undef" values in the list.
4398
4399       If there are no more rows or if an error occurs, then "fetchrow_array"
4400       returns an empty list. You should check "$sth->err" afterwards (or use
4401       the "RaiseError" attribute) to discover if the empty list returned was
4402       due to an error.
4403
4404       If called in a scalar context for a statement handle that has more than
4405       one column, it is undefined whether the driver will return the value of
4406       the first column or the last. So don't do that.  Also, in a scalar
4407       context, an "undef" is returned if there are no more rows or if an
4408       error occurred. That "undef" can't be distinguished from an "undef"
4409       returned because the first field value was NULL.  For these reasons you
4410       should exercise some caution if you use "fetchrow_array" in a scalar
4411       context.
4412
4413       "fetchrow_hashref"
4414
4415        $hash_ref = $sth->fetchrow_hashref;
4416        $hash_ref = $sth->fetchrow_hashref($name);
4417
4418       An alternative to "fetchrow_arrayref". Fetches the next row of data and
4419       returns it as a reference to a hash containing field name and field
4420       value pairs.  Null fields are returned as "undef" values in the hash.
4421
4422       If there are no more rows or if an error occurs, then
4423       "fetchrow_hashref" returns an "undef". You should check "$sth->err"
4424       afterwards (or use the "RaiseError" attribute) to discover if the
4425       "undef" returned was due to an error.
4426
4427       The optional $name parameter specifies the name of the statement handle
4428       attribute. For historical reasons it defaults to ""NAME"", however
4429       using either ""NAME_lc"" or ""NAME_uc"" is recommended for portability.
4430
4431       The keys of the hash are the same names returned by "$sth->{$name}". If
4432       more than one field has the same name, there will only be one entry in
4433       the returned hash for those fields, so statements like ""select foo,
4434       foo from bar"" will return only a single key from "fetchrow_hashref".
4435       In these cases use column aliases or "fetchrow_arrayref".  Note that it
4436       is the database server (and not the DBD implementation) which provides
4437       the name for fields containing functions like "count(*)" or
4438       ""max(c_foo)"" and they may clash with existing column names (most
4439       databases don't care about duplicate column names in a result-set). If
4440       you want these to return as unique names that are the same across
4441       databases, use aliases, as in ""select count(*) as cnt"" or ""select
4442       max(c_foo) mx_foo, ..."" depending on the syntax your database
4443       supports.
4444
4445       Because of the extra work "fetchrow_hashref" and Perl have to perform,
4446       it is not as efficient as "fetchrow_arrayref" or "fetchrow_array".
4447
4448       By default a reference to a new hash is returned for each row.  It is
4449       likely that a future version of the DBI will support an attribute which
4450       will enable the same hash to be reused for each row. This will give a
4451       significant performance boost, but it won't be enabled by default
4452       because of the risk of breaking old code.
4453
4454       "fetchall_arrayref"
4455
4456         $tbl_ary_ref = $sth->fetchall_arrayref;
4457         $tbl_ary_ref = $sth->fetchall_arrayref( $slice );
4458         $tbl_ary_ref = $sth->fetchall_arrayref( $slice, $max_rows  );
4459
4460       The "fetchall_arrayref" method can be used to fetch all the data to be
4461       returned from a prepared and executed statement handle. It returns a
4462       reference to an array that contains one reference per row.
4463
4464       If called on an inactive statement handle, "fetchall_arrayref" returns
4465       undef.
4466
4467       If there are no rows left to return from an active statement handle,
4468       "fetchall_arrayref" returns a reference to an empty array. If an error
4469       occurs, "fetchall_arrayref" returns the data fetched thus far, which
4470       may be none.  You should check "$sth->err" afterwards (or use the
4471       "RaiseError" attribute) to discover if the data is complete or was
4472       truncated due to an error.
4473
4474       If $slice is an array reference, "fetchall_arrayref" uses
4475       "fetchrow_arrayref" to fetch each row as an array ref. If the $slice
4476       array is not empty then it is used as a slice to select individual
4477       columns by perl array index number (starting at 0, unlike column and
4478       parameter numbers which start at 1).
4479
4480       With no parameters, or if $slice is undefined, "fetchall_arrayref" acts
4481       as if passed an empty array ref.
4482
4483       For example, to fetch just the first column of every row:
4484
4485         $tbl_ary_ref = $sth->fetchall_arrayref([0]);
4486
4487       To fetch the second to last and last column of every row:
4488
4489         $tbl_ary_ref = $sth->fetchall_arrayref([-2,-1]);
4490
4491       Those two examples both return a reference to an array of array refs.
4492
4493       If $slice is a hash reference, "fetchall_arrayref" fetches each row as
4494       a hash reference. If the $slice hash is empty then the keys in the
4495       hashes have whatever name lettercase is returned by default. (See
4496       "FetchHashKeyName" attribute.) If the $slice hash is not empty, then it
4497       is used as a slice to select individual columns by name. The values of
4498       the hash should be set to 1.  The key names of the returned hashes
4499       match the letter case of the names in the parameter hash, regardless of
4500       the "FetchHashKeyName" attribute.
4501
4502       For example, to fetch all fields of every row as a hash ref:
4503
4504         $tbl_ary_ref = $sth->fetchall_arrayref({});
4505
4506       To fetch only the fields called "foo" and "bar" of every row as a hash
4507       ref (with keys named "foo" and "BAR", regardless of the original
4508       capitalization):
4509
4510         $tbl_ary_ref = $sth->fetchall_arrayref({ foo=>1, BAR=>1 });
4511
4512       Those two examples both return a reference to an array of hash refs.
4513
4514       If $slice is a reference to a hash reference, that hash is used to
4515       select and rename columns. The keys are 0-based column index numbers
4516       and the values are the corresponding keys for the returned row hashes.
4517
4518       For example, to fetch only the first and second columns of every row as
4519       a hash ref (with keys named "k" and "v" regardless of their original
4520       names):
4521
4522         $tbl_ary_ref = $sth->fetchall_arrayref( \{ 0 => 'k', 1 => 'v' } );
4523
4524       If $max_rows is defined and greater than or equal to zero then it is
4525       used to limit the number of rows fetched before returning.
4526       fetchall_arrayref() can then be called again to fetch more rows.  This
4527       is especially useful when you need the better performance of
4528       fetchall_arrayref() but don't have enough memory to fetch and return
4529       all the rows in one go.
4530
4531       Here's an example (assumes RaiseError is enabled):
4532
4533         my $rows = []; # cache for batches of rows
4534         while( my $row = ( shift(@$rows) || # get row from cache, or reload cache:
4535                            shift(@{$rows=$sth->fetchall_arrayref(undef,10_000)||[]}) )
4536         ) {
4537           ...
4538         }
4539
4540       That might be the fastest way to fetch and process lots of rows using
4541       the DBI, but it depends on the relative cost of method calls vs memory
4542       allocation.
4543
4544       A standard "while" loop with column binding is often faster because the
4545       cost of allocating memory for the batch of rows is greater than the
4546       saving by reducing method calls. It's possible that the DBI may provide
4547       a way to reuse the memory of a previous batch in future, which would
4548       then shift the balance back towards fetchall_arrayref().
4549
4550       "fetchall_hashref"
4551
4552         $hash_ref = $sth->fetchall_hashref($key_field);
4553
4554       The "fetchall_hashref" method can be used to fetch all the data to be
4555       returned from a prepared and executed statement handle. It returns a
4556       reference to a hash containing a key for each distinct value of the
4557       $key_field column that was fetched. For each key the corresponding
4558       value is a reference to a hash containing all the selected columns and
4559       their values, as returned by "fetchrow_hashref()".
4560
4561       If there are no rows to return, "fetchall_hashref" returns a reference
4562       to an empty hash. If an error occurs, "fetchall_hashref" returns the
4563       data fetched thus far, which may be none.  You should check "$sth->err"
4564       afterwards (or use the "RaiseError" attribute) to discover if the data
4565       is complete or was truncated due to an error.
4566
4567       The $key_field parameter provides the name of the field that holds the
4568       value to be used for the key for the returned hash.  For example:
4569
4570         $dbh->{FetchHashKeyName} = 'NAME_lc';
4571         $sth = $dbh->prepare("SELECT FOO, BAR, ID, NAME, BAZ FROM TABLE");
4572         $sth->execute;
4573         $hash_ref = $sth->fetchall_hashref('id');
4574         print "Name for id 42 is $hash_ref->{42}->{name}\n";
4575
4576       The $key_field parameter can also be specified as an integer column
4577       number (counting from 1).  If $key_field doesn't match any column in
4578       the statement, as a name first then as a number, then an error is
4579       returned.
4580
4581       For queries returning more than one 'key' column, you can specify
4582       multiple column names by passing $key_field as a reference to an array
4583       containing one or more key column names (or index numbers).  For
4584       example:
4585
4586         $sth = $dbh->prepare("SELECT foo, bar, baz FROM table");
4587         $sth->execute;
4588         $hash_ref = $sth->fetchall_hashref( [ qw(foo bar) ] );
4589         print "For foo 42 and bar 38, baz is $hash_ref->{42}->{38}->{baz}\n";
4590
4591       The fetchall_hashref() method is normally used only where the key
4592       fields values for each row are unique.  If multiple rows are returned
4593       with the same values for the key fields then later rows overwrite
4594       earlier ones.
4595
4596       "finish"
4597
4598         $rc  = $sth->finish;
4599
4600       Indicate that no more data will be fetched from this statement handle
4601       before it is either executed again or destroyed.  You almost certainly
4602       do not need to call this method.
4603
4604       Adding calls to "finish" after loop that fetches all rows is a common
4605       mistake, don't do it, it can mask genuine problems like uncaught fetch
4606       errors.
4607
4608       When all the data has been fetched from a "SELECT" statement, the
4609       driver will automatically call "finish" for you. So you should not call
4610       it explicitly except when you know that you've not fetched all the data
4611       from a statement handle and the handle won't be destroyed soon.
4612
4613       The most common example is when you only want to fetch just one row,
4614       but in that case the "selectrow_*" methods are usually better anyway.
4615
4616       Consider a query like:
4617
4618         SELECT foo FROM table WHERE bar=? ORDER BY baz
4619
4620       on a very large table. When executed, the database server will have to
4621       use temporary buffer space to store the sorted rows. If, after
4622       executing the handle and selecting just a few rows, the handle won't be
4623       re-executed for some time and won't be destroyed, the "finish" method
4624       can be used to tell the server that the buffer space can be freed.
4625
4626       Calling "finish" resets the "Active" attribute for the statement.  It
4627       may also make some statement handle attributes (such as "NAME" and
4628       "TYPE") unavailable if they have not already been accessed (and thus
4629       cached).
4630
4631       The "finish" method does not affect the transaction status of the
4632       database connection.  It has nothing to do with transactions. It's
4633       mostly an internal "housekeeping" method that is rarely needed.  See
4634       also "disconnect" and the "Active" attribute.
4635
4636       The "finish" method should have been called "discard_pending_rows".
4637
4638       "rows"
4639
4640         $rv = $sth->rows;
4641
4642       Returns the number of rows affected by the last row affecting command,
4643       or -1 if the number of rows is not known or not available.
4644
4645       Generally, you can only rely on a row count after a non-"SELECT"
4646       "execute" (for some specific operations like "UPDATE" and "DELETE"), or
4647       after fetching all the rows of a "SELECT" statement.
4648
4649       For "SELECT" statements, it is generally not possible to know how many
4650       rows will be returned except by fetching them all.  Some drivers will
4651       return the number of rows the application has fetched so far, but
4652       others may return -1 until all rows have been fetched.  So use of the
4653       "rows" method or $DBI::rows with "SELECT" statements is not
4654       recommended.
4655
4656       One alternative method to get a row count for a "SELECT" is to execute
4657       a "SELECT COUNT(*) FROM ..." SQL statement with the same "..." as your
4658       query and then fetch the row count from that.
4659
4660       "bind_col"
4661
4662         $rc = $sth->bind_col($column_number, \$var_to_bind);
4663         $rc = $sth->bind_col($column_number, \$var_to_bind, \%attr );
4664         $rc = $sth->bind_col($column_number, \$var_to_bind, $bind_type );
4665
4666       Binds a Perl variable and/or some attributes to an output column
4667       (field) of a "SELECT" statement.  Column numbers count up from 1.  You
4668       do not need to bind output columns in order to fetch data.  For maximum
4669       portability between drivers, bind_col() should be called after
4670       execute() and not before.  See also "bind_columns" for an example.
4671
4672       The binding is performed at a low level using Perl aliasing.  Whenever
4673       a row is fetched from the database $var_to_bind appears to be
4674       automatically updated simply because it now refers to the same memory
4675       location as the corresponding column value.  This makes using bound
4676       variables very efficient.  Binding a tied variable doesn't work,
4677       currently.
4678
4679       The "bind_param" method performs a similar, but opposite, function for
4680       input variables.
4681
4682       Data Types for Column Binding
4683
4684       The "\%attr" parameter can be used to hint at the data type formatting
4685       the column should have. For example, you can use:
4686
4687         $sth->bind_col(1, undef, { TYPE => SQL_DATETIME });
4688
4689       to specify that you'd like the column (which presumably is some kind of
4690       datetime type) to be returned in the standard format for SQL_DATETIME,
4691       which is 'YYYY-MM-DD HH:MM:SS', rather than the native formatting the
4692       database would normally use.
4693
4694       There's no $var_to_bind in that example to emphasize the point that
4695       bind_col() works on the underlying column and not just a particular
4696       bound variable.
4697
4698       As a short-cut for the common case, the data type can be passed
4699       directly, in place of the "\%attr" hash reference. This example is
4700       equivalent to the one above:
4701
4702         $sth->bind_col(1, undef, SQL_DATETIME);
4703
4704       The "TYPE" value indicates the standard (non-driver-specific) type for
4705       this parameter. To specify the driver-specific type, the driver may
4706       support a driver-specific attribute, such as "{ ora_type => 97 }".
4707
4708       The SQL_DATETIME and other related constants can be imported using
4709
4710         use DBI qw(:sql_types);
4711
4712       See "DBI Constants" for more information.
4713
4714       Few drivers support specifying a data type via a "bind_col" call (most
4715       will simply ignore the data type). Fewer still allow the data type to
4716       be altered once set. If you do set a column type the type should remain
4717       sticky through further calls to bind_col for the same column if the
4718       type is not overridden (this is important for instance when you are
4719       using a slice in fetchall_arrayref).
4720
4721       The TYPE attribute for bind_col() was first specified in DBI 1.41.
4722
4723       From DBI 1.611, drivers can use the "TYPE" attribute to attempt to cast
4724       the bound scalar to a perl type which more closely matches "TYPE". At
4725       present DBI supports "SQL_INTEGER", "SQL_DOUBLE" and "SQL_NUMERIC". See
4726       "sql_type_cast" for details of how types are cast.
4727
4728       Other attributes for Column Binding
4729
4730       The "\%attr" parameter may also contain the following attributes:
4731
4732       "StrictlyTyped"
4733           If a "TYPE" attribute is passed to bind_col, then the driver will
4734           attempt to change the bound perl scalar to match the type more
4735           closely. If the bound value cannot be cast to the requested "TYPE"
4736           then by default it is left untouched and no error is generated. If
4737           you specify "StrictlyTyped" as 1 and the cast fails, this will
4738           generate an error.
4739
4740           This attribute was first added in DBI 1.611. When 1.611 was
4741           released few drivers actually supported this attribute but
4742           DBD::Oracle and DBD::ODBC should from versions 1.24.
4743
4744       "DiscardString"
4745           When the "TYPE" attribute is passed to "bind_col" and the driver
4746           successfully casts the bound perl scalar to a non-string type then
4747           if "DiscardString" is set to 1, the string portion of the scalar
4748           will be discarded. By default, "DiscardString" is not set.
4749
4750           This attribute was first added in DBI 1.611. When 1.611 was
4751           released few drivers actually supported this attribute but
4752           DBD::Oracle and DBD::ODBC should from versions 1.24.
4753
4754       "bind_columns"
4755
4756         $rc = $sth->bind_columns(@list_of_refs_to_vars_to_bind);
4757
4758       Calls "bind_col" for each column of the "SELECT" statement.
4759
4760       The list of references should have the same number of elements as the
4761       number of columns in the "SELECT" statement. If it doesn't then
4762       "bind_columns" will bind the elements given, up to the number of
4763       columns, and then return an error.
4764
4765       For maximum portability between drivers, bind_columns() should be
4766       called after execute() and not before.
4767
4768       For example:
4769
4770         $dbh->{RaiseError} = 1; # do this, or check every call for errors
4771         $sth = $dbh->prepare(q{ SELECT region, sales FROM sales_by_region });
4772         $sth->execute;
4773         my ($region, $sales);
4774
4775         # Bind Perl variables to columns:
4776         $rv = $sth->bind_columns(\$region, \$sales);
4777
4778         # you can also use Perl's \(...) syntax (see perlref docs):
4779         #     $sth->bind_columns(\($region, $sales));
4780
4781         # Column binding is the most efficient way to fetch data
4782         while ($sth->fetch) {
4783             print "$region: $sales\n";
4784         }
4785
4786       For compatibility with old scripts, the first parameter will be ignored
4787       if it is "undef" or a hash reference.
4788
4789       Here's a more fancy example that binds columns to the values inside a
4790       hash (thanks to H.Merijn Brand):
4791
4792         $sth->execute;
4793         my %row;
4794         $sth->bind_columns( \( @row{ @{$sth->{NAME_lc} } } ));
4795         while ($sth->fetch) {
4796             print "$row{region}: $row{sales}\n";
4797         }
4798
4799       "dump_results"
4800
4801         $rows = $sth->dump_results($maxlen, $lsep, $fsep, $fh);
4802
4803       Fetches all the rows from $sth, calls "DBI::neat_list" for each row,
4804       and prints the results to $fh (defaults to "STDOUT") separated by $lsep
4805       (default "\n"). $fsep defaults to ", " and $maxlen defaults to 35.
4806
4807       This method is designed as a handy utility for prototyping and testing
4808       queries. Since it uses "neat_list" to format and edit the string for
4809       reading by humans, it is not recommended for data transfer
4810       applications.
4811
4812   Statement Handle Attributes
4813       This section describes attributes specific to statement handles. Most
4814       of these attributes are read-only.
4815
4816       Changes to these statement handle attributes do not affect any other
4817       existing or future statement handles.
4818
4819       Attempting to set or get the value of an unknown attribute generates a
4820       warning, except for private driver specific attributes (which all have
4821       names starting with a lowercase letter).
4822
4823       Example:
4824
4825         ... = $h->{NUM_OF_FIELDS};    # get/read
4826
4827       Some drivers cannot provide valid values for some or all of these
4828       attributes until after "$sth->execute" has been successfully called.
4829       Typically the attribute will be "undef" in these situations.
4830
4831       Some attributes, like NAME, are not appropriate to some types of
4832       statement, like SELECT. Typically the attribute will be "undef" in
4833       these situations.
4834
4835       For drivers which support stored procedures and multiple result sets
4836       (see "more_results") these attributes relate to the current result set.
4837
4838       See also "finish" to learn more about the effect it may have on some
4839       attributes.
4840
4841       "NUM_OF_FIELDS"
4842
4843       Type: integer, read-only
4844
4845       Number of fields (columns) in the data the prepared statement may
4846       return.  Statements that don't return rows of data, like "DELETE" and
4847       "CREATE" set "NUM_OF_FIELDS" to 0 (though it may be undef in some
4848       drivers).
4849
4850       "NUM_OF_PARAMS"
4851
4852       Type: integer, read-only
4853
4854       The number of parameters (placeholders) in the prepared statement.  See
4855       SUBSTITUTION VARIABLES below for more details.
4856
4857       "NAME"
4858
4859       Type: array-ref, read-only
4860
4861       Returns a reference to an array of field names for each column. The
4862       names may contain spaces but should not be truncated or have any
4863       trailing space. Note that the names have the letter case (upper, lower
4864       or mixed) as returned by the driver being used. Portable applications
4865       should use "NAME_lc" or "NAME_uc".
4866
4867         print "First column name: $sth->{NAME}->[0]\n";
4868
4869       Also note that the name returned for (aggregate) functions like
4870       count(*) or "max(c_foo)" is determined by the database server and not
4871       by "DBI" or the "DBD" backend.
4872
4873       "NAME_lc"
4874
4875       Type: array-ref, read-only
4876
4877       Like "/NAME" but always returns lowercase names.
4878
4879       "NAME_uc"
4880
4881       Type: array-ref, read-only
4882
4883       Like "/NAME" but always returns uppercase names.
4884
4885       "NAME_hash"
4886
4887       Type: hash-ref, read-only
4888
4889       "NAME_lc_hash"
4890
4891       Type: hash-ref, read-only
4892
4893       "NAME_uc_hash"
4894
4895       Type: hash-ref, read-only
4896
4897       The "NAME_hash", "NAME_lc_hash", and "NAME_uc_hash" attributes return
4898       column name information as a reference to a hash.
4899
4900       The keys of the hash are the names of the columns.  The letter case of
4901       the keys corresponds to the letter case returned by the "NAME",
4902       "NAME_lc", and "NAME_uc" attributes respectively (as described above).
4903
4904       The value of each hash entry is the perl index number of the
4905       corresponding column (counting from 0). For example:
4906
4907         $sth = $dbh->prepare("select Id, Name from table");
4908         $sth->execute;
4909         @row = $sth->fetchrow_array;
4910         print "Name $row[ $sth->{NAME_lc_hash}{name} ]\n";
4911
4912       "TYPE"
4913
4914       Type: array-ref, read-only
4915
4916       Returns a reference to an array of integer values for each column. The
4917       value indicates the data type of the corresponding column.
4918
4919       The values correspond to the international standards (ANSI X3.135 and
4920       ISO/IEC 9075) which, in general terms, means ODBC. Driver-specific
4921       types that don't exactly match standard types should generally return
4922       the same values as an ODBC driver supplied by the makers of the
4923       database. That might include private type numbers in ranges the vendor
4924       has officially registered with the ISO working group:
4925
4926         ftp://sqlstandards.org/SC32/SQL_Registry/
4927
4928       Where there's no vendor-supplied ODBC driver to be compatible with, the
4929       DBI driver can use type numbers in the range that is now officially
4930       reserved for use by the DBI: -9999 to -9000.
4931
4932       All possible values for "TYPE" should have at least one entry in the
4933       output of the "type_info_all" method (see "type_info_all").
4934
4935       "PRECISION"
4936
4937       Type: array-ref, read-only
4938
4939       Returns a reference to an array of integer values for each column.
4940
4941       For numeric columns, the value is the maximum number of digits (without
4942       considering a sign character or decimal point). Note that the "display
4943       size" for floating point types (REAL, FLOAT, DOUBLE) can be up to 7
4944       characters greater than the precision (for the sign + decimal point +
4945       the letter E + a sign + 2 or 3 digits).
4946
4947       For any character type column the value is the OCTET_LENGTH, in other
4948       words the number of bytes, not characters.
4949
4950       (More recent standards refer to this as COLUMN_SIZE but we stick with
4951       PRECISION for backwards compatibility.)
4952
4953       "SCALE"
4954
4955       Type: array-ref, read-only
4956
4957       Returns a reference to an array of integer values for each column.
4958       NULL ("undef") values indicate columns where scale is not applicable.
4959
4960       "NULLABLE"
4961
4962       Type: array-ref, read-only
4963
4964       Returns a reference to an array indicating the possibility of each
4965       column returning a null.  Possible values are 0 (or an empty string) =
4966       no, 1 = yes, 2 = unknown.
4967
4968         print "First column may return NULL\n" if $sth->{NULLABLE}->[0];
4969
4970       "CursorName"
4971
4972       Type: string, read-only
4973
4974       Returns the name of the cursor associated with the statement handle, if
4975       available. If not available or if the database driver does not support
4976       the "where current of ..." SQL syntax, then it returns "undef".
4977
4978       "Database"
4979
4980       Type: dbh, read-only
4981
4982       Returns the parent $dbh of the statement handle.
4983
4984       "Statement"
4985
4986       Type: string, read-only
4987
4988       Returns the statement string passed to the "prepare" method.
4989
4990       "ParamValues"
4991
4992       Type: hash ref, read-only
4993
4994       Returns a reference to a hash containing the values currently bound to
4995       placeholders.  The keys of the hash are the 'names' of the
4996       placeholders, typically integers starting at 1.  Returns undef if not
4997       supported by the driver.
4998
4999       See "ShowErrorStatement" for an example of how this is used.
5000
5001       * Keys:
5002
5003       If the driver supports "ParamValues" but no values have been bound yet
5004       then the driver should return a hash with placeholders names in the
5005       keys but all the values undef, but some drivers may return a ref to an
5006       empty hash because they can't pre-determine the names.
5007
5008       It is possible that the keys in the hash returned by "ParamValues" are
5009       not exactly the same as those implied by the prepared statement.  For
5010       example, DBD::Oracle translates '"?"' placeholders into '":pN"' where N
5011       is a sequence number starting at 1.
5012
5013       * Values:
5014
5015       It is possible that the values in the hash returned by "ParamValues"
5016       are not exactly the same as those passed to bind_param() or execute().
5017       The driver may have slightly modified values in some way based on the
5018       TYPE the value was bound with. For example a floating point value bound
5019       as an SQL_INTEGER type may be returned as an integer.  The values
5020       returned by "ParamValues" can be passed to another bind_param() method
5021       with the same TYPE and will be seen by the database as the same value.
5022       See also "ParamTypes" below.
5023
5024       The "ParamValues" attribute was added in DBI 1.28.
5025
5026       "ParamTypes"
5027
5028       Type: hash ref, read-only
5029
5030       Returns a reference to a hash containing the type information currently
5031       bound to placeholders.  Returns undef if not supported by the driver.
5032
5033       * Keys:
5034
5035       See "ParamValues" above.
5036
5037       * Values:
5038
5039       The hash values are hashrefs of type information in the same form as
5040       that passed to the various bind_param() methods (See "bind_param" for
5041       the format and values).
5042
5043       It is possible that the values in the hash returned by "ParamTypes" are
5044       not exactly the same as those passed to bind_param() or execute().
5045       Param attributes specified using the abbreviated form, like this:
5046
5047           $sth->bind_param(1, SQL_INTEGER);
5048
5049       are returned in the expanded form, as if called like this:
5050
5051           $sth->bind_param(1, { TYPE => SQL_INTEGER });
5052
5053       The driver may have modified the type information in some way based on
5054       the bound values, other hints provided by the prepare()'d SQL
5055       statement, or alternate type mappings required by the driver or target
5056       database system. The driver may also add private keys (with names
5057       beginning with the drivers reserved prefix, e.g., odbc_xxx).
5058
5059       * Example:
5060
5061       The keys and values in the returned hash can be passed to the various
5062       bind_param() methods to effectively reproduce a previous param binding.
5063       For example:
5064
5065         # assuming $sth1 is a previously prepared statement handle
5066         my $sth2 = $dbh->prepare( $sth1->{Statement} );
5067         my $ParamValues = $sth1->{ParamValues} || {};
5068         my $ParamTypes  = $sth1->{ParamTypes}  || {};
5069         $sth2->bind_param($_, $ParamValues->{$_}, $ParamTypes->{$_})
5070           for keys %{ {%$ParamValues, %$ParamTypes} };
5071         $sth2->execute();
5072
5073       The "ParamTypes" attribute was added in DBI 1.49. Implementation is the
5074       responsibility of individual drivers; the DBI layer default
5075       implementation simply returns undef.
5076
5077       "ParamArrays"
5078
5079       Type: hash ref, read-only
5080
5081       Returns a reference to a hash containing the values currently bound to
5082       placeholders with "execute_array" or "bind_param_array".  The keys of
5083       the hash are the 'names' of the placeholders, typically integers
5084       starting at 1.  Returns undef if not supported by the driver or no
5085       arrays of parameters are bound.
5086
5087       Each key value is an array reference containing a list of the bound
5088       parameters for that column.
5089
5090       For example:
5091
5092         $sth = $dbh->prepare("INSERT INTO staff (id, name) values (?,?)");
5093         $sth->execute_array({},[1,2], ['fred','dave']);
5094         if ($sth->{ParamArrays}) {
5095             foreach $param (keys %{$sth->{ParamArrays}}) {
5096                 printf "Parameters for %s : %s\n", $param,
5097                 join(",", @{$sth->{ParamArrays}->{$param}});
5098             }
5099         }
5100
5101       It is possible that the values in the hash returned by "ParamArrays"
5102       are not exactly the same as those passed to "bind_param_array" or
5103       "execute_array".  The driver may have slightly modified values in some
5104       way based on the TYPE the value was bound with. For example a floating
5105       point value bound as an SQL_INTEGER type may be returned as an integer.
5106
5107       It is also possible that the keys in the hash returned by "ParamArrays"
5108       are not exactly the same as those implied by the prepared statement.
5109       For example, DBD::Oracle translates '"?"'  placeholders into '":pN"'
5110       where N is a sequence number starting at 1.
5111
5112       "RowsInCache"
5113
5114       Type: integer, read-only
5115
5116       If the driver supports a local row cache for "SELECT" statements, then
5117       this attribute holds the number of un-fetched rows in the cache. If the
5118       driver doesn't, then it returns "undef". Note that some drivers pre-
5119       fetch rows on execute, whereas others wait till the first fetch.
5120
5121       See also the "RowCacheSize" database handle attribute.
5122

FURTHER INFORMATION

5124   Catalog Methods
5125       An application can retrieve metadata information from the DBMS by
5126       issuing appropriate queries on the views of the Information Schema.
5127       Unfortunately, "INFORMATION_SCHEMA" views are seldom supported by the
5128       DBMS.  Special methods (catalog methods) are available to return result
5129       sets for a small but important portion of that metadata:
5130
5131         column_info
5132         foreign_key_info
5133         primary_key_info
5134         table_info
5135         statistics_info
5136
5137       All catalog methods accept arguments in order to restrict the result
5138       sets.  Passing "undef" to an optional argument does not constrain the
5139       search for that argument.  However, an empty string ('') is treated as
5140       a regular search criteria and will only match an empty value.
5141
5142       Note: SQL/CLI and ODBC differ in the handling of empty strings. An
5143       empty string will not restrict the result set in SQL/CLI.
5144
5145       Most arguments in the catalog methods accept only ordinary values, e.g.
5146       the arguments of "primary_key_info()".  Such arguments are treated as a
5147       literal string, i.e. the case is significant and quote characters are
5148       taken literally.
5149
5150       Some arguments in the catalog methods accept search patterns (strings
5151       containing '_' and/or '%'), e.g. the $table argument of
5152       "column_info()".  Passing '%' is equivalent to leaving the argument
5153       "undef".
5154
5155       Caveat: The underscore ('_') is valid and often used in SQL
5156       identifiers.  Passing such a value to a search pattern argument may
5157       return more rows than expected!  To include pattern characters as
5158       literals, they must be preceded by an escape character which can be
5159       achieved with
5160
5161         $esc = $dbh->get_info( 14 );  # SQL_SEARCH_PATTERN_ESCAPE
5162         $search_pattern =~ s/([_%])/$esc$1/g;
5163
5164       The ODBC and SQL/CLI specifications define a way to change the default
5165       behaviour described above: All arguments (except list value arguments)
5166       are treated as identifier if the "SQL_ATTR_METADATA_ID" attribute is
5167       set to "SQL_TRUE".  Quoted identifiers are very similar to ordinary
5168       values, i.e. their body (the string within the quotes) is interpreted
5169       literally.  Unquoted identifiers are compared in UPPERCASE.
5170
5171       The DBI (currently) does not support the "SQL_ATTR_METADATA_ID"
5172       attribute, i.e. it behaves like an ODBC driver where
5173       "SQL_ATTR_METADATA_ID" is set to "SQL_FALSE".
5174
5175   Transactions
5176       Transactions are a fundamental part of any robust database system. They
5177       protect against errors and database corruption by ensuring that sets of
5178       related changes to the database take place in atomic (indivisible, all-
5179       or-nothing) units.
5180
5181       This section applies to databases that support transactions and where
5182       "AutoCommit" is off.  See "AutoCommit" for details of using
5183       "AutoCommit" with various types of databases.
5184
5185       The recommended way to implement robust transactions in Perl
5186       applications is to enable "RaiseError" and catch the error that's
5187       'thrown' as an exception.  For example, using Try::Tiny:
5188
5189         use Try::Tiny;
5190         $dbh->{AutoCommit} = 0;  # enable transactions, if possible
5191         $dbh->{RaiseError} = 1;
5192         try {
5193             foo(...)        # do lots of work here
5194             bar(...)        # including inserts
5195             baz(...)        # and updates
5196             $dbh->commit;   # commit the changes if we get this far
5197         } catch {
5198             warn "Transaction aborted because $_"; # Try::Tiny copies $@ into $_
5199             # now rollback to undo the incomplete changes
5200             # but do it in an eval{} as it may also fail
5201             eval { $dbh->rollback };
5202             # add other application on-error-clean-up code here
5203         };
5204
5205       If the "RaiseError" attribute is not set, then DBI calls would need to
5206       be manually checked for errors, typically like this:
5207
5208         $h->method(@args) or die $h->errstr;
5209
5210       With "RaiseError" set, the DBI will automatically "die" if any DBI
5211       method call on that handle (or a child handle) fails, so you don't have
5212       to test the return value of each method call. See "RaiseError" for more
5213       details.
5214
5215       A major advantage of the "eval" approach is that the transaction will
5216       be properly rolled back if any code (not just DBI calls) in the inner
5217       application dies for any reason. The major advantage of using the
5218       "$h->{RaiseError}" attribute is that all DBI calls will be checked
5219       automatically. Both techniques are strongly recommended.
5220
5221       After calling "commit" or "rollback" many drivers will not let you
5222       fetch from a previously active "SELECT" statement handle that's a child
5223       of the same database handle. A typical way round this is to connect the
5224       the database twice and use one connection for "SELECT" statements.
5225
5226       See "AutoCommit" and "disconnect" for other important information about
5227       transactions.
5228
5229   Handling BLOB / LONG / Memo Fields
5230       Many databases support "blob" (binary large objects), "long", or
5231       similar datatypes for holding very long strings or large amounts of
5232       binary data in a single field. Some databases support variable length
5233       long values over 2,000,000,000 bytes in length.
5234
5235       Since values of that size can't usually be held in memory, and because
5236       databases can't usually know in advance the length of the longest long
5237       that will be returned from a "SELECT" statement (unlike other data
5238       types), some special handling is required.
5239
5240       In this situation, the value of the "$h->{LongReadLen}" attribute is
5241       used to determine how much buffer space to allocate when fetching such
5242       fields.  The "$h->{LongTruncOk}" attribute is used to determine how to
5243       behave if a fetched value can't fit into the buffer.
5244
5245       See the description of "LongReadLen" for more information.
5246
5247       When trying to insert long or binary values, placeholders should be
5248       used since there are often limits on the maximum size of an "INSERT"
5249       statement and the "quote" method generally can't cope with binary data.
5250       See "Placeholders and Bind Values".
5251
5252   Simple Examples
5253       Here's a complete example program to select and fetch some data:
5254
5255         my $data_source = "dbi::DriverName:db_name";
5256         my $dbh = DBI->connect($data_source, $user, $password)
5257             or die "Can't connect to $data_source: $DBI::errstr";
5258
5259         my $sth = $dbh->prepare( q{
5260                 SELECT name, phone
5261                 FROM mytelbook
5262         }) or die "Can't prepare statement: $DBI::errstr";
5263
5264         my $rc = $sth->execute
5265             or die "Can't execute statement: $DBI::errstr";
5266
5267         print "Query will return $sth->{NUM_OF_FIELDS} fields.\n\n";
5268         print "Field names: @{ $sth->{NAME} }\n";
5269
5270         while (($name, $phone) = $sth->fetchrow_array) {
5271             print "$name: $phone\n";
5272         }
5273         # check for problems which may have terminated the fetch early
5274         die $sth->errstr if $sth->err;
5275
5276         $dbh->disconnect;
5277
5278       Here's a complete example program to insert some data from a file.
5279       (This example uses "RaiseError" to avoid needing to check each call).
5280
5281         my $dbh = DBI->connect("dbi:DriverName:db_name", $user, $password, {
5282             RaiseError => 1, AutoCommit => 0
5283         });
5284
5285         my $sth = $dbh->prepare( q{
5286             INSERT INTO table (name, phone) VALUES (?, ?)
5287         });
5288
5289         open FH, "<phone.csv" or die "Unable to open phone.csv: $!";
5290         while (<FH>) {
5291             chomp;
5292             my ($name, $phone) = split /,/;
5293             $sth->execute($name, $phone);
5294         }
5295         close FH;
5296
5297         $dbh->commit;
5298         $dbh->disconnect;
5299
5300       Here's how to convert fetched NULLs (undefined values) into empty
5301       strings:
5302
5303         while($row = $sth->fetchrow_arrayref) {
5304           # this is a fast and simple way to deal with nulls:
5305           foreach (@$row) { $_ = '' unless defined }
5306           print "@$row\n";
5307         }
5308
5309       The "q{...}" style quoting used in these examples avoids clashing with
5310       quotes that may be used in the SQL statement. Use the double-quote like
5311       "qq{...}" operator if you want to interpolate variables into the
5312       string.  See "Quote and Quote-like Operators" in perlop for more
5313       details.
5314
5315   Threads and Thread Safety
5316       Perl 5.7 and later support a new threading model called iThreads.  (The
5317       old "5.005 style" threads are not supported by the DBI.)
5318
5319       In the iThreads model each thread has its own copy of the perl
5320       interpreter.  When a new thread is created the original perl
5321       interpreter is 'cloned' to create a new copy for the new thread.
5322
5323       If the DBI and drivers are loaded and handles created before the thread
5324       is created then it will get a cloned copy of the DBI, the drivers and
5325       the handles.
5326
5327       However, the internal pointer data within the handles will refer to the
5328       DBI and drivers in the original interpreter. Using those handles in the
5329       new interpreter thread is not safe, so the DBI detects this and croaks
5330       on any method call using handles that don't belong to the current
5331       thread (except for DESTROY).
5332
5333       Because of this (possibly temporary) restriction, newly created threads
5334       must make their own connections to the database. Handles can't be
5335       shared across threads.
5336
5337       But BEWARE, some underlying database APIs (the code the DBD driver uses
5338       to talk to the database, often supplied by the database vendor) are not
5339       thread safe. If it's not thread safe, then allowing more than one
5340       thread to enter the code at the same time may cause subtle/serious
5341       problems. In some cases allowing more than one thread to enter the
5342       code, even if not at the same time, can cause problems. You have been
5343       warned.
5344
5345       Using DBI with perl threads is not yet recommended for production
5346       environments. For more information see
5347       <http://www.perlmonks.org/index.pl?node_id=288022>
5348
5349       Note: There is a bug in perl 5.8.2 when configured with threads and
5350       debugging enabled (bug #24463) which causes a DBI test to fail.
5351
5352   Signal Handling and Canceling Operations
5353       [The following only applies to systems with unix-like signal handling.
5354       I'd welcome additions for other systems, especially Windows.]
5355
5356       The first thing to say is that signal handling in Perl versions less
5357       than 5.8 is not safe. There is always a small risk of Perl crashing
5358       and/or core dumping when, or after, handling a signal because the
5359       signal could arrive and be handled while internal data structures are
5360       being changed. If the signal handling code used those same internal
5361       data structures it could cause all manner of subtle and not-so-subtle
5362       problems.  The risk was reduced with 5.4.4 but was still present in all
5363       perls up through 5.8.0.
5364
5365       Beginning in perl 5.8.0 perl implements 'safe' signal handling if your
5366       system has the POSIX sigaction() routine. Now when a signal is
5367       delivered perl just makes a note of it but does not run the %SIG
5368       handler. The handling is 'deferred' until a 'safe' moment.
5369
5370       Although this change made signal handling safe, it also lead to a
5371       problem with signals being deferred for longer than you'd like.  If a
5372       signal arrived while executing a system call, such as waiting for data
5373       on a network connection, the signal is noted and then the system call
5374       that was executing returns with an EINTR error code to indicate that it
5375       was interrupted. All fine so far.
5376
5377       The problem comes when the code that made the system call sees the
5378       EINTR code and decides it's going to call it again. Perl doesn't do
5379       that, but database code sometimes does. If that happens then the signal
5380       handler doesn't get called until later. Maybe much later.
5381
5382       Fortunately there are ways around this which we'll discuss below.
5383       Unfortunately they make signals unsafe again.
5384
5385       The two most common uses of signals in relation to the DBI are for
5386       canceling operations when the user types Ctrl-C (interrupt), and for
5387       implementing a timeout using "alarm()" and $SIG{ALRM}.
5388
5389       Cancel
5390           The DBI provides a "cancel" method for statement handles. The
5391           "cancel" method should abort the current operation and is designed
5392           to be called from a signal handler.  For example:
5393
5394             $SIG{INT} = sub { $sth->cancel };
5395
5396           However, few drivers implement this (the DBI provides a default
5397           method that just returns "undef") and, even if implemented, there
5398           is still a possibility that the statement handle, and even the
5399           parent database handle, will not be usable afterwards.
5400
5401           If "cancel" returns true, then it has successfully invoked the
5402           database engine's own cancel function.  If it returns false, then
5403           "cancel" failed. If it returns "undef", then the database driver
5404           does not have cancel implemented - very few do.
5405
5406       Timeout
5407           The traditional way to implement a timeout is to set $SIG{ALRM} to
5408           refer to some code that will be executed when an ALRM signal
5409           arrives and then to call alarm($seconds) to schedule an ALRM signal
5410           to be delivered $seconds in the future. For example:
5411
5412             my $failed;
5413             eval {
5414               local $SIG{ALRM} = sub { die "TIMEOUT\n" }; # N.B. \n required
5415               eval {
5416                 alarm($seconds);
5417                 ... code to execute with timeout here (which may die) ...
5418                 1;
5419               } or $failed = 1;
5420               # outer eval catches alarm that might fire JUST before this alarm(0)
5421               alarm(0);  # cancel alarm (if code ran fast)
5422               die "$@" if $failed;
5423               1;
5424             } or $failed = 1;
5425             if ( $failed ) {
5426               if ( defined $@ and $@ eq "TIMEOUT\n" ) { ... }
5427               else { ... } # some other error
5428             }
5429
5430           The first (outer) eval is used to avoid the unlikely but possible
5431           chance that the "code to execute" dies and the alarm fires before
5432           it is cancelled. Without the outer eval, if this happened your
5433           program will die if you have no ALRM handler or a non-local alarm
5434           handler will be called.
5435
5436           Unfortunately, as described above, this won't always work as
5437           expected, depending on your perl version and the underlying
5438           database code.
5439
5440           With Oracle for instance (DBD::Oracle), if the system which hosts
5441           the database is down the DBI->connect() call will hang for several
5442           minutes before returning an error.
5443
5444       The solution on these systems is to use the "POSIX::sigaction()"
5445       routine to gain low level access to how the signal handler is
5446       installed.
5447
5448       The code would look something like this (for the DBD-Oracle connect()):
5449
5450          use POSIX qw(:signal_h);
5451
5452          my $mask = POSIX::SigSet->new( SIGALRM ); # signals to mask in the handler
5453          my $action = POSIX::SigAction->new(
5454              sub { die "connect timeout\n" },        # the handler code ref
5455              $mask,
5456              # not using (perl 5.8.2 and later) 'safe' switch or sa_flags
5457          );
5458          my $oldaction = POSIX::SigAction->new();
5459          sigaction( SIGALRM, $action, $oldaction );
5460          my $dbh;
5461          my $failed;
5462          eval {
5463             eval {
5464               alarm(5); # seconds before time out
5465               $dbh = DBI->connect("dbi:Oracle:$dsn" ... );
5466               1;
5467             } or $failed = 1;
5468             alarm(0); # cancel alarm (if connect worked fast)
5469             die "$@\n" if $failed; # connect died
5470             1;
5471          } or $failed = 1;
5472          sigaction( SIGALRM, $oldaction );  # restore original signal handler
5473          if ( $failed ) {
5474            if ( defined $@ and $@ eq "connect timeout\n" ) {...}
5475            else { # connect died }
5476          }
5477
5478       See previous example for the reasoning around the double eval.
5479
5480       Similar techniques can be used for canceling statement execution.
5481
5482       Unfortunately, this solution is somewhat messy, and it does not work
5483       with perl versions less than perl 5.8 where "POSIX::sigaction()"
5484       appears to be broken.
5485
5486       For a cleaner implementation that works across perl versions, see
5487       Lincoln Baxter's Sys::SigAction module at Sys::SigAction.  The
5488       documentation for Sys::SigAction includes an longer discussion of this
5489       problem, and a DBD::Oracle test script.
5490
5491       Be sure to read all the signal handling sections of the perlipc manual.
5492
5493       And finally, two more points to keep firmly in mind. Firstly, remember
5494       that what we've done here is essentially revert to old style unsafe
5495       handling of these signals. So do as little as possible in the handler.
5496       Ideally just die(). Secondly, the handles in use at the time the signal
5497       is handled may not be safe to use afterwards.
5498
5499   Subclassing the DBI
5500       DBI can be subclassed and extended just like any other object oriented
5501       module.  Before we talk about how to do that, it's important to be
5502       clear about the various DBI classes and how they work together.
5503
5504       By default "$dbh = DBI->connect(...)" returns a $dbh blessed into the
5505       "DBI::db" class.  And the "$dbh->prepare" method returns an $sth
5506       blessed into the "DBI::st" class (actually it simply changes the last
5507       four characters of the calling handle class to be "::st").
5508
5509       The leading '"DBI"' is known as the 'root class' and the extra '"::db"'
5510       or '"::st"' are the 'handle type suffixes'. If you want to subclass the
5511       DBI you'll need to put your overriding methods into the appropriate
5512       classes.  For example, if you want to use a root class of "MySubDBI"
5513       and override the do(), prepare() and execute() methods, then your do()
5514       and prepare() methods should be in the "MySubDBI::db" class and the
5515       execute() method should be in the "MySubDBI::st" class.
5516
5517       To setup the inheritance hierarchy the @ISA variable in "MySubDBI::db"
5518       should include "DBI::db" and the @ISA variable in "MySubDBI::st" should
5519       include "DBI::st".  The "MySubDBI" root class itself isn't currently
5520       used for anything visible and so, apart from setting @ISA to include
5521       "DBI", it can be left empty.
5522
5523       So, having put your overriding methods into the right classes, and
5524       setup the inheritance hierarchy, how do you get the DBI to use them?
5525       You have two choices, either a static method call using the name of
5526       your subclass:
5527
5528         $dbh = MySubDBI->connect(...);
5529
5530       or specifying a "RootClass" attribute:
5531
5532         $dbh = DBI->connect(..., { RootClass => 'MySubDBI' });
5533
5534       If both forms are used then the attribute takes precedence.
5535
5536       The only differences between the two are that using an explicit
5537       RootClass attribute will a) make the DBI automatically attempt to load
5538       a module by that name if the class doesn't exist, and b) won't call
5539       your MySubDBI::connect() method, if you have one.
5540
5541       When subclassing is being used then, after a successful new connect,
5542       the DBI->connect method automatically calls:
5543
5544         $dbh->connected($dsn, $user, $pass, \%attr);
5545
5546       The default method does nothing. The call is made just to simplify any
5547       post-connection setup that your subclass may want to perform.  The
5548       parameters are the same as passed to DBI->connect.  If your subclass
5549       supplies a connected method, it should be part of the MySubDBI::db
5550       package.
5551
5552       One more thing to note: you must let the DBI do the handle creation.
5553       If you want to override the connect() method in your *::dr class then
5554       it must still call SUPER::connect to get a $dbh to work with.
5555       Similarly, an overridden prepare() method in *::db must still call
5556       SUPER::prepare to get a $sth.  If you try to create your own handles
5557       using bless() then you'll find the DBI will reject them with an "is not
5558       a DBI handle (has no magic)" error.
5559
5560       Here's a brief example of a DBI subclass.  A more thorough example can
5561       be found in t/subclass.t in the DBI distribution.
5562
5563         package MySubDBI;
5564
5565         use strict;
5566
5567         use DBI;
5568         use vars qw(@ISA);
5569         @ISA = qw(DBI);
5570
5571         package MySubDBI::db;
5572         use vars qw(@ISA);
5573         @ISA = qw(DBI::db);
5574
5575         sub prepare {
5576           my ($dbh, @args) = @_;
5577           my $sth = $dbh->SUPER::prepare(@args)
5578               or return;
5579           $sth->{private_mysubdbi_info} = { foo => 'bar' };
5580           return $sth;
5581         }
5582
5583         package MySubDBI::st;
5584         use vars qw(@ISA);
5585         @ISA = qw(DBI::st);
5586
5587         sub fetch {
5588           my ($sth, @args) = @_;
5589           my $row = $sth->SUPER::fetch(@args)
5590               or return;
5591           do_something_magical_with_row_data($row)
5592               or return $sth->set_err(1234, "The magic failed", undef, "fetch");
5593           return $row;
5594         }
5595
5596       When calling a SUPER::method that returns a handle, be careful to check
5597       the return value before trying to do other things with it in your
5598       overridden method. This is especially important if you want to set a
5599       hash attribute on the handle, as Perl's autovivification will bite you
5600       by (in)conveniently creating an unblessed hashref, which your method
5601       will then return with usually baffling results later on like the error
5602       "dbih_getcom handle HASH(0xa4451a8) is not a DBI handle (has no magic".
5603       It's best to check right after the call and return undef immediately on
5604       error, just like DBI would and just like the example above.
5605
5606       If your method needs to record an error it should call the set_err()
5607       method with the error code and error string, as shown in the example
5608       above. The error code and error string will be recorded in the handle
5609       and available via "$h->err" and $DBI::errstr etc.  The set_err() method
5610       always returns an undef or empty list as appropriate. Since your method
5611       should nearly always return an undef or empty list as soon as an error
5612       is detected it's handy to simply return what set_err() returns, as
5613       shown in the example above.
5614
5615       If the handle has "RaiseError", "PrintError", or "HandleError" etc. set
5616       then the set_err() method will honour them. This means that if
5617       "RaiseError" is set then set_err() won't return in the normal way but
5618       will 'throw an exception' that can be caught with an "eval" block.
5619
5620       You can stash private data into DBI handles via "$h->{private_..._*}".
5621       See the entry under "ATTRIBUTES COMMON TO ALL HANDLES" for info and
5622       important caveats.
5623
5624   Memory Leaks
5625       When tracking down memory leaks using tools like Devel::Leak you'll
5626       find that some DBI internals are reported as 'leaking' memory.  This is
5627       very unlikely to be a real leak.  The DBI has various caches to improve
5628       performance and the apparrent leaks are simply the normal operation of
5629       these caches.
5630
5631       The most frequent sources of the apparrent leaks are "ChildHandles",
5632       "prepare_cached" and "connect_cached".
5633
5634       For example
5635       http://stackoverflow.com/questions/13338308/perl-dbi-memory-leak
5636
5637       Given how widely the DBI is used, you can rest assured that if a new
5638       release of the DBI did have a real leak it would be discovered,
5639       reported, and fixed immediately. The leak you're looking for is
5640       probably elsewhere. Good luck!
5641

TRACING

5643       The DBI has a powerful tracing mechanism built in. It enables you to
5644       see what's going on 'behind the scenes', both within the DBI and the
5645       drivers you're using.
5646
5647   Trace Settings
5648       Which details are written to the trace output is controlled by a
5649       combination of a trace level, an integer from 0 to 15, and a set of
5650       trace flags that are either on or off. Together these are known as the
5651       trace settings and are stored together in a single integer.  For normal
5652       use you only need to set the trace level, and generally only to a value
5653       between 1 and 4.
5654
5655       Each handle has its own trace settings, and so does the DBI.  When you
5656       call a method the DBI merges the handles settings into its own for the
5657       duration of the call: the trace flags of the handle are OR'd into the
5658       trace flags of the DBI, and if the handle has a higher trace level then
5659       the DBI trace level is raised to match it.  The previous DBI trace
5660       settings are restored when the called method returns.
5661
5662   Trace Levels
5663       Trace levels are as follows:
5664
5665         0 - Trace disabled.
5666         1 - Trace top-level DBI method calls returning with results or errors.
5667         2 - As above, adding tracing of top-level method entry with parameters.
5668         3 - As above, adding some high-level information from the driver
5669             and some internal information from the DBI.
5670         4 - As above, adding more detailed information from the driver.
5671             This is the first level to trace all the rows being fetched.
5672         5 to 15 - As above but with more and more internal information.
5673
5674       Trace level 1 is best for a simple overview of what's happening.  Trace
5675       levels 2 thru 4 a good choice for general purpose tracing.  Levels 5
5676       and above are best reserved for investigating a specific problem, when
5677       you need to see "inside" the driver and DBI.
5678
5679       The trace output is detailed and typically very useful. Much of the
5680       trace output is formatted using the "neat" function, so strings in the
5681       trace output may be edited and truncated by that function.
5682
5683   Trace Flags
5684       Trace flags are used to enable tracing of specific activities within
5685       the DBI and drivers. The DBI defines some trace flags and drivers can
5686       define others. DBI trace flag names begin with a capital letter and
5687       driver specific names begin with a lowercase letter, as usual.
5688
5689       Currently the DBI defines these trace flags:
5690
5691         ALL - turn on all DBI and driver flags (not recommended)
5692         SQL - trace SQL statements executed
5693               (not yet implemented in DBI but implemented in some DBDs)
5694         CON - trace connection process
5695         ENC - trace encoding (unicode translations etc)
5696               (not yet implemented in DBI but implemented in some DBDs)
5697         DBD - trace only DBD messages
5698               (not implemented by all DBDs yet)
5699         TXN - trace transactions
5700               (not implemented in all DBDs yet)
5701
5702       The "parse_trace_flags" and "parse_trace_flag" methods are used to
5703       convert trace flag names into the corresponding integer bit flags.
5704
5705   Enabling Trace
5706       The "$h->trace" method sets the trace settings for a handle and
5707       "DBI->trace" does the same for the DBI.
5708
5709       In addition to the "trace" method, you can enable the same trace
5710       information, and direct the output to a file, by setting the
5711       "DBI_TRACE" environment variable before starting Perl.  See "DBI_TRACE"
5712       for more information.
5713
5714       Finally, you can set, or get, the trace settings for a handle using the
5715       "TraceLevel" attribute.
5716
5717       All of those methods use parse_trace_flags() and so allow you set both
5718       the trace level and multiple trace flags by using a string containing
5719       the trace level and/or flag names separated by vertical bar (""|"") or
5720       comma ("","") characters. For example:
5721
5722         local $h->{TraceLevel} = "3|SQL|foo";
5723
5724   Trace Output
5725       Initially trace output is written to "STDERR".  Both the "$h->trace"
5726       and "DBI->trace" methods take an optional $trace_file parameter, which
5727       may be either the name of a file to be opened by DBI in append mode, or
5728       a reference to an existing writable (possibly layered) filehandle. If
5729       $trace_file is a filename, and can be opened in append mode, or
5730       $trace_file is a writable filehandle, then all trace output (currently
5731       including that from other handles) is redirected to that file. A
5732       warning is generated if $trace_file can't be opened or is not writable.
5733
5734       Further calls to trace() without $trace_file do not alter where the
5735       trace output is sent. If $trace_file is undefined, then trace output is
5736       sent to "STDERR" and, if the prior trace was opened with $trace_file as
5737       a filename, the previous trace file is closed; if $trace_file was a
5738       filehandle, the filehandle is not closed.
5739
5740       NOTE: If $trace_file is specified as a filehandle, the filehandle
5741       should not be closed until all DBI operations are completed, or the
5742       application has reset the trace file via another call to "trace()" that
5743       changes the trace file.
5744
5745   Tracing to Layered Filehandles
5746       NOTE:
5747
5748       ·   Tied filehandles are not currently supported, as tie operations are
5749           not available to the PerlIO methods used by the DBI.
5750
5751       ·   PerlIO layer support requires Perl version 5.8 or higher.
5752
5753       As of version 5.8, Perl provides the ability to layer various
5754       "disciplines" on an open filehandle via the PerlIO module.
5755
5756       A simple example of using PerlIO layers is to use a scalar as the
5757       output:
5758
5759           my $scalar = '';
5760           open( my $fh, "+>:scalar", \$scalar );
5761           $dbh->trace( 2, $fh );
5762
5763       Now all trace output is simply appended to $scalar.
5764
5765       A more complex application of tracing to a layered filehandle is the
5766       use of a custom layer (Refer to Perlio::via for details on creating
5767       custom PerlIO layers.). Consider an application with the following
5768       logger module:
5769
5770           package MyFancyLogger;
5771
5772           sub new
5773           {
5774               my $self = {};
5775               my $fh;
5776               open $fh, '>', 'fancylog.log';
5777               $self->{_fh} = $fh;
5778               $self->{_buf} = '';
5779               return bless $self, shift;
5780           }
5781
5782           sub log
5783           {
5784               my $self = shift;
5785               return unless exists $self->{_fh};
5786               my $fh = $self->{_fh};
5787               $self->{_buf} .= shift;
5788           #
5789           # DBI feeds us pieces at a time, so accumulate a complete line
5790           # before outputing
5791           #
5792               print $fh "At ", scalar localtime(), ':', $self->{_buf}, "\n" and
5793               $self->{_buf} = ''
5794                   if $self->{_buf}=~tr/\n//;
5795           }
5796
5797           sub close {
5798               my $self = shift;
5799               return unless exists $self->{_fh};
5800               my $fh = $self->{_fh};
5801               print $fh "At ", scalar localtime(), ':', $self->{_buf}, "\n" and
5802               $self->{_buf} = ''
5803                   if $self->{_buf};
5804               close $fh;
5805               delete $self->{_fh};
5806           }
5807
5808           1;
5809
5810       To redirect DBI traces to this logger requires creating a package for
5811       the layer:
5812
5813           package PerlIO::via::MyFancyLogLayer;
5814
5815           sub PUSHED
5816           {
5817               my ($class,$mode,$fh) = @_;
5818               my $logger;
5819               return bless \$logger,$class;
5820           }
5821
5822           sub OPEN {
5823               my ($self, $path, $mode, $fh) = @_;
5824               #
5825               # $path is actually our logger object
5826               #
5827               $$self = $path;
5828               return 1;
5829           }
5830
5831           sub WRITE
5832           {
5833               my ($self, $buf, $fh) = @_;
5834               $$self->log($buf);
5835               return length($buf);
5836           }
5837
5838           sub CLOSE {
5839               my $self = shift;
5840               $$self->close();
5841               return 0;
5842           }
5843
5844           1;
5845
5846       The application can then cause DBI traces to be routed to the logger
5847       using
5848
5849           use PerlIO::via::MyFancyLogLayer;
5850
5851           open my $fh, '>:via(MyFancyLogLayer)', MyFancyLogger->new();
5852
5853           $dbh->trace('SQL', $fh);
5854
5855       Now all trace output will be processed by MyFancyLogger's log() method.
5856
5857   Trace Content
5858       Many of the values embedded in trace output are formatted using the
5859       neat() utility function. This means they may be quoted, sanitized, and
5860       possibly truncated if longer than $DBI::neat_maxlen. See "neat" for
5861       more details.
5862
5863   Tracing Tips
5864       You can add tracing to your own application code using the "trace_msg"
5865       method.
5866
5867       It can sometimes be handy to compare trace files from two different
5868       runs of the same script. However using a tool like "diff" on the
5869       original log output doesn't work well because the trace file is full of
5870       object addresses that may differ on each run.
5871
5872       The DBI includes a handy utility called dbilogstrip that can be used to
5873       'normalize' the log content. It can be used as a filter like this:
5874
5875           DBI_TRACE=2 perl yourscript.pl ...args1... 2>&1 | dbilogstrip > dbitrace1.log
5876           DBI_TRACE=2 perl yourscript.pl ...args2... 2>&1 | dbilogstrip > dbitrace2.log
5877           diff -u dbitrace1.log dbitrace2.log
5878
5879       See dbilogstrip for more information.
5880

DBI ENVIRONMENT VARIABLES

5882       The DBI module recognizes a number of environment variables, but most
5883       of them should not be used most of the time.  It is better to be
5884       explicit about what you are doing to avoid the need for environment
5885       variables, especially in a web serving system where web servers are
5886       stingy about which environment variables are available.
5887
5888   DBI_DSN
5889       The DBI_DSN environment variable is used by DBI->connect if you do not
5890       specify a data source when you issue the connect.  It should have a
5891       format such as "dbi:Driver:databasename".
5892
5893   DBI_DRIVER
5894       The DBI_DRIVER environment variable is used to fill in the database
5895       driver name in DBI->connect if the data source string starts "dbi::"
5896       (thereby omitting the driver).  If DBI_DSN omits the driver name,
5897       DBI_DRIVER can fill the gap.
5898
5899   DBI_AUTOPROXY
5900       The DBI_AUTOPROXY environment variable takes a string value that starts
5901       "dbi:Proxy:" and is typically followed by "hostname=...;port=...".  It
5902       is used to alter the behaviour of DBI->connect.  For full details, see
5903       DBI::Proxy documentation.
5904
5905   DBI_USER
5906       The DBI_USER environment variable takes a string value that is used as
5907       the user name if the DBI->connect call is given undef (as distinct from
5908       an empty string) as the username argument.  Be wary of the security
5909       implications of using this.
5910
5911   DBI_PASS
5912       The DBI_PASS environment variable takes a string value that is used as
5913       the password if the DBI->connect call is given undef (as distinct from
5914       an empty string) as the password argument.  Be extra wary of the
5915       security implications of using this.
5916
5917   DBI_DBNAME (obsolete)
5918       The DBI_DBNAME environment variable takes a string value that is used
5919       only when the obsolescent style of DBI->connect (with driver name as
5920       fourth parameter) is used, and when no value is provided for the first
5921       (database name) argument.
5922
5923   DBI_TRACE
5924       The DBI_TRACE environment variable specifies the global default trace
5925       settings for the DBI at startup. Can also be used to direct trace
5926       output to a file. When the DBI is loaded it does:
5927
5928         DBI->trace(split /=/, $ENV{DBI_TRACE}, 2) if $ENV{DBI_TRACE};
5929
5930       So if "DBI_TRACE" contains an ""="" character then what follows it is
5931       used as the name of the file to append the trace to.
5932
5933       output appended to that file. If the name begins with a number followed
5934       by an equal sign ("="), then the number and the equal sign are stripped
5935       off from the name, and the number is used to set the trace level. For
5936       example:
5937
5938         DBI_TRACE=1=dbitrace.log perl your_test_script.pl
5939
5940       On Unix-like systems using a Bourne-like shell, you can do this easily
5941       on the command line:
5942
5943         DBI_TRACE=2 perl your_test_script.pl
5944
5945       See "TRACING" for more information.
5946
5947   PERL_DBI_DEBUG (obsolete)
5948       An old variable that should no longer be used; equivalent to DBI_TRACE.
5949
5950   DBI_PROFILE
5951       The DBI_PROFILE environment variable can be used to enable profiling of
5952       DBI method calls. See DBI::Profile for more information.
5953
5954   DBI_PUREPERL
5955       The DBI_PUREPERL environment variable can be used to enable the use of
5956       DBI::PurePerl.  See DBI::PurePerl for more information.
5957

WARNING AND ERROR MESSAGES

5959   Fatal Errors
5960       Can't call method "prepare" without a package or object reference
5961           The $dbh handle you're using to call "prepare" is probably
5962           undefined because the preceding "connect" failed. You should always
5963           check the return status of DBI methods, or use the "RaiseError"
5964           attribute.
5965
5966       Can't call method "execute" without a package or object reference
5967           The $sth handle you're using to call "execute" is probably
5968           undefined because the preceding "prepare" failed. You should always
5969           check the return status of DBI methods, or use the "RaiseError"
5970           attribute.
5971
5972       DBI/DBD internal version mismatch
5973           The DBD driver module was built with a different version of DBI
5974           than the one currently being used.  You should rebuild the DBD
5975           module under the current version of DBI.
5976
5977           (Some rare platforms require "static linking". On those platforms,
5978           there may be an old DBI or DBD driver version actually embedded in
5979           the Perl executable being used.)
5980
5981       DBD driver has not implemented the AutoCommit attribute
5982           The DBD driver implementation is incomplete. Consult the author.
5983
5984       Can't [sg]et %s->{%s}: unrecognised attribute
5985           You attempted to set or get an unknown attribute of a handle.  Make
5986           sure you have spelled the attribute name correctly; case is
5987           significant (e.g., "Autocommit" is not the same as "AutoCommit").
5988

Pure-Perl DBI

5990       A pure-perl emulation of the DBI is included in the distribution for
5991       people using pure-perl drivers who, for whatever reason, can't install
5992       the compiled DBI. See DBI::PurePerl.
5993

SEE ALSO

5995   Driver and Database Documentation
5996       Refer to the documentation for the DBD driver that you are using.
5997
5998       Refer to the SQL Language Reference Manual for the database engine that
5999       you are using.
6000
6001   ODBC and SQL/CLI Standards Reference Information
6002       More detailed information about the semantics of certain DBI methods
6003       that are based on ODBC and SQL/CLI standards is available on-line via
6004       microsoft.com, for ODBC, and www.jtc1sc32.org for the SQL/CLI standard:
6005
6006        DBI method        ODBC function     SQL/CLI Working Draft
6007        ----------        -------------     ---------------------
6008        column_info       SQLColumns        Page 124
6009        foreign_key_info  SQLForeignKeys    Page 163
6010        get_info          SQLGetInfo        Page 214
6011        primary_key_info  SQLPrimaryKeys    Page 254
6012        table_info        SQLTables         Page 294
6013        type_info         SQLGetTypeInfo    Page 239
6014        statistics_info   SQLStatistics
6015
6016       To find documentation on the ODBC function you can use the MSDN search
6017       facility at:
6018
6019           http://msdn.microsoft.com/Search
6020
6021       and search for something like "SQLColumns returns".
6022
6023       And for SQL/CLI standard information on SQLColumns you'd read page 124
6024       of the (very large) SQL/CLI Working Draft available from:
6025
6026         http://jtc1sc32.org/doc/N0701-0750/32N0744T.pdf
6027
6028   Standards Reference Information
6029       A hyperlinked, browsable version of the BNF syntax for SQL92 (plus
6030       Oracle 7 SQL and PL/SQL) is available here:
6031
6032         http://cui.unige.ch/db-research/Enseignement/analyseinfo/SQL92/BNFindex.html
6033
6034       You can find more information about SQL standards online by searching
6035       for the appropriate standard names and numbers. For example, searching
6036       for "ANSI/ISO/IEC International Standard (IS) Database Language SQL -
6037       Part 1: SQL/Framework" you'll find a copy at:
6038
6039         ftp://ftp.iks-jena.de/mitarb/lutz/standards/sql/ansi-iso-9075-1-1999.pdf
6040
6041   Books and Articles
6042       Programming the Perl DBI, by Alligator Descartes and Tim Bunce.
6043       <http://books.perl.org/book/154>
6044
6045       Programming Perl 3rd Ed. by Larry Wall, Tom Christiansen & Jon Orwant.
6046       <http://books.perl.org/book/134>
6047
6048       Learning Perl by Randal Schwartz.  <http://books.perl.org/book/101>
6049
6050       Details of many other books related to perl can be found at
6051       <http://books.perl.org>
6052
6053   Perl Modules
6054       Index of DBI related modules available from CPAN:
6055
6056        L<https://metacpan.org/search?q=DBD%3A%3A>
6057        L<https://metacpan.org/search?q=DBIx%3A%3A>
6058        L<https://metacpan.org/search?q=DBI>
6059
6060       For a good comparison of RDBMS-OO mappers and some OO-RDBMS mappers
6061       (including Class::DBI, Alzabo, and DBIx::RecordSet in the former
6062       category and Tangram and SPOPS in the latter) see the Perl Object-
6063       Oriented Persistence project pages at:
6064
6065        http://poop.sourceforge.net
6066
6067       A similar page for Java toolkits can be found at:
6068
6069        http://c2.com/cgi-bin/wiki?ObjectRelationalToolComparison
6070
6071   Mailing List
6072       The dbi-users mailing list is the primary means of communication among
6073       users of the DBI and its related modules. For details send email to:
6074
6075        L<dbi-users-help@perl.org>
6076
6077       There are typically between 700 and 900 messages per month.  You have
6078       to subscribe in order to be able to post. However you can opt for a
6079       'post-only' subscription.
6080
6081       Mailing list archives (of variable quality) are held at:
6082
6083        http://groups.google.com/groups?group=perl.dbi.users
6084        http://www.xray.mpe.mpg.de/mailing-lists/dbi/
6085        http://www.mail-archive.com/dbi-users%40perl.org/
6086
6087   Assorted Related Links
6088       The DBI "Home Page":
6089
6090        http://dbi.perl.org/
6091
6092       Other DBI related links:
6093
6094        http://www.perlmonks.org/?node=DBI%20recipes
6095        http://www.perlmonks.org/?node=Speeding%20up%20the%20DBI
6096
6097       Other database related links:
6098
6099        http://www.connectionstrings.com/
6100
6101       Security, especially the "SQL Injection" attack:
6102
6103        http://bobby-tables.com/
6104        http://online.securityfocus.com/infocus/1644
6105
6106   FAQ
6107       See <http://faq.dbi-support.com/>
6108

AUTHORS

6110       DBI by Tim Bunce, <http://www.tim.bunce.name>
6111
6112       This pod text by Tim Bunce, J. Douglas Dunlop, Jonathan Leffler and
6113       others.  Perl by Larry Wall and the "perl5-porters".
6114
6116       The DBI module is Copyright (c) 1994-2012 Tim Bunce. Ireland.  All
6117       rights reserved.
6118
6119       You may distribute under the terms of either the GNU General Public
6120       License or the Artistic License, as specified in the Perl 5.10.0 README
6121       file.
6122

SUPPORT / WARRANTY

6124       The DBI is free Open Source software. IT COMES WITHOUT WARRANTY OF ANY
6125       KIND.
6126
6127   Support
6128       My consulting company, Data Plan Services, offers annual and multi-
6129       annual support contracts for the DBI. These provide sustained support
6130       for DBI development, and sustained value for you in return.  Contact me
6131       for details.
6132
6133   Sponsor Enhancements
6134       If your company would benefit from a specific new DBI feature, please
6135       consider sponsoring its development.  Work is performed rapidly, and
6136       usually on a fixed-price payment-on-delivery basis.  Contact me for
6137       details.
6138
6139       Using such targeted financing allows you to contribute to DBI
6140       development, and rapidly get something specific and valuable in return.
6141

ACKNOWLEDGEMENTS

6143       I would like to acknowledge the valuable contributions of the many
6144       people I have worked with on the DBI project, especially in the early
6145       years (1992-1994). In no particular order: Kevin Stock, Buzz Moschetti,
6146       Kurt Andersen, Ted Lemon, William Hails, Garth Kennedy, Michael
6147       Peppler, Neil S. Briscoe, Jeff Urlwin, David J. Hughes, Jeff Stander,
6148       Forrest D Whitcher, Larry Wall, Jeff Fried, Roy Johnson, Paul Hudson,
6149       Georg Rehfeld, Steve Sizemore, Ron Pool, Jon Meek, Tom Christiansen,
6150       Steve Baumgarten, Randal Schwartz, and a whole lot more.
6151
6152       Then, of course, there are the poor souls who have struggled through
6153       untold and undocumented obstacles to actually implement DBI drivers.
6154       Among their ranks are Jochen Wiedmann, Alligator Descartes, Jonathan
6155       Leffler, Jeff Urlwin, Michael Peppler, Henrik Tougaard, Edwin Pratomo,
6156       Davide Migliavacca, Jan Pazdziora, Peter Haworth, Edmund Mergl, Steve
6157       Williams, Thomas Lowery, and Phlip Plumlee. Without them, the DBI would
6158       not be the practical reality it is today.  I'm also especially grateful
6159       to Alligator Descartes for starting work on the first edition of the
6160       "Programming the Perl DBI" book and letting me jump on board.
6161
6162       The DBI and DBD::Oracle were originally developed while I was Technical
6163       Director (CTO) of the Paul Ingram Group in the UK.  So I'd especially
6164       like to thank Paul for his generosity and vision in supporting this
6165       work for many years.
6166
6167       A couple of specific DBI features have been sponsored by enlightened
6168       companies:
6169
6170       The development of the swap_inner_handle() method was sponsored by
6171       BizRate.com (<http://BizRate.com>)
6172
6173       The development of DBD::Gofer and related modules was sponsored by
6174       Shopzilla.com (<http://Shopzilla.com>), where I currently work.
6175

CONTRIBUTING

6177       As you can see above, many people have contributed to the DBI and
6178       drivers in many ways over many years.
6179
6180       If you'd like to help then see <http://dbi.perl.org/contributing>.
6181
6182       If you'd like the DBI to do something new or different then a good way
6183       to make that happen is to do it yourself and send me a patch to the
6184       source code that shows the changes. (But read "Speak before you patch"
6185       below.)
6186
6187   Browsing the source code repository
6188       Use https://github.com/perl5-dbi/dbi
6189
6190   How to create a patch using Git
6191       The DBI source code is maintained using Git.  To access the source
6192       you'll need to install a Git client. Then, to get the source code, do:
6193
6194         git clone https://github.com/perl5-dbi/dbi.git DBI-git
6195
6196       The source code will now be available in the new subdirectory
6197       "DBI-git".
6198
6199       When you want to synchronize later, issue the command
6200
6201         git pull --all
6202
6203       Make your changes, test them, test them again until everything passes.
6204       If there are no tests for the new feature you added or a behaviour
6205       change, the change should include a new test. Then commit the changes.
6206       Either use
6207
6208         git gui
6209
6210       or
6211
6212         git commit -a -m 'Message to my changes'
6213
6214       If you get any conflicts reported you'll need to fix them first.
6215
6216       Then generate the patch file to be mailed:
6217
6218         git format-patch -1 --attach
6219
6220       which will create a file 0001-*.patch (where * relates to the commit
6221       message).  Read the patch file, as a sanity check, and then email it to
6222       dbi-dev@perl.org.
6223
6224       If you have a github <https://github.com> account, you can also fork
6225       the repository, commit your changes to the forked repository and then
6226       do a pull request.
6227
6228   How to create a patch without Git
6229       Unpack a fresh copy of the distribution:
6230
6231         wget http://cpan.metacpan.org/authors/id/T/TI/TIMB/DBI-1.627.tar.gz
6232         tar xfz DBI-1.627.tar.gz
6233
6234       Rename the newly created top level directory:
6235
6236         mv DBI-1.627 DBI-1.627.your_foo
6237
6238       Edit the contents of DBI-1.627.your_foo/* till it does what you want.
6239
6240       Test your changes and then remove all temporary files:
6241
6242         make test && make distclean
6243
6244       Go back to the directory you originally unpacked the distribution:
6245
6246         cd ..
6247
6248       Unpack another copy of the original distribution you started with:
6249
6250         tar xfz DBI-1.627.tar.gz
6251
6252       Then create a patch file by performing a recursive "diff" on the two
6253       top level directories:
6254
6255         diff -purd DBI-1.627 DBI-1.627.your_foo > DBI-1.627.your_foo.patch
6256
6257   Speak before you patch
6258       For anything non-trivial or possibly controversial it's a good idea to
6259       discuss (on dbi-dev@perl.org) the changes you propose before actually
6260       spending time working on them. Otherwise you run the risk of them being
6261       rejected because they don't fit into some larger plans you may not be
6262       aware of.
6263
6264       You can also reach the developers on IRC (chat). If they are on-line,
6265       the most likely place to talk to them is the #dbi channel on
6266       irc.perl.org
6267

TRANSLATIONS

6269       A German translation of this manual (possibly slightly out of date) is
6270       available, thanks to O'Reilly, at:
6271
6272         http://www.oreilly.de/catalog/perldbiger/
6273
6275       Apache::DBI
6276           To be used with the Apache daemon together with an embedded Perl
6277           interpreter like "mod_perl". Establishes a database connection
6278           which remains open for the lifetime of the HTTP daemon. This way
6279           the CGI connect and disconnect for every database access becomes
6280           superfluous.
6281
6282       SQL Parser
6283           See also the SQL::Statement module, SQL parser and engine.
6284
6285
6286
6287perl v5.28.1                      2018-10-28                            DBI(3)
Impressum