use DBI; my $dsn = "DBI:MariaDB:database=$database;host=$hostname;port=$port"; my $dbh = DBI->connect($dsn, $user, $password); my $sth = $dbh->prepare( 'SELECT id, first_name, last_name FROM authors WHERE last_name = ?' ) or die 'prepare statement failed: ' . $dbh->errstr(); $sth->execute('Eggers') or die 'execution failed: ' . $dbh->errstr(); print $sth->rows() . " rows found.\n"; while (my $ref = $sth->fetchrow_hashref()) { print "Found a row: id = $ref->{'id'}, fn = $ref->{'first_name'}\n"; }
#!/usr/bin/perl use strict; use warnings; use DBI; # Connect to the database. my $dbh = DBI->connect('DBI:MariaDB:database=test;host=localhost', 'joe', q(joe's password), { RaiseError => 1, PrintError => 0 }); # Drop table 'foo'. This may fail, if 'foo' doesn't exist # Thus we put an eval around it. eval { $dbh->do('DROP TABLE foo'); } or do { print 'Dropping foo failed: ' . $dbh->errstr() . "\n"; }; # Create a new table 'foo'. This must not fail, thus we don't # catch errors. $dbh->do('CREATE TABLE foo (id INTEGER, name VARCHAR(20))'); # INSERT some data into 'foo' using placeholders $dbh->do('INSERT INTO foo VALUES (?, ?)', undef, 2, 'Jochen'); # now retrieve data from the table. my $sth = $dbh->prepare('SELECT * FROM foo'); $sth->execute(); while (my $ref = $sth->fetchrow_hashref()) { print "Found a row: id = $ref->{'id'}, name = $ref->{'name'}\n"; } # Disconnect from the database. $dbh->disconnect();
In what follows we first discuss the use of DBD::MariaDB, because this is what you will need the most. For installation, see the separate document DBD::MariaDB::INSTALL. See ``EXAMPLE'' for a simple example above.
From perl you activate the interface with the statement
use DBI;
After that you can connect to multiple MariaDB and MySQL database servers and send multiple queries to any of them via a simple object oriented interface. Two types of objects are available: database handles and statement handles. Perl returns a database handle to the connect method like so:
my $dbh = DBI->connect("DBI:MariaDB:database=$db;host=$host", $user, $password, { RaiseError => 1, PrintError => 0 });
Once you have connected to a database, you can execute SQL statements with:
$dbh->do('INSERT INTO foo VALUES (?, ?)', undef, $number, $name);
See DBI do method for details. See also the bind_param method in DBI. See ``DATABASE HANDLES'' below for more details on database handles.
If you want to retrieve results, you need to create a so-called statement handle with:
my $sth = $dbh->prepare('SELECT * FROM ' . $dbh->quote_identifier($table)); $sth->execute();
This statement handle can be used for multiple things. First of all you can retrieve a row of data:
my $row = $sth->fetchrow_hashref();
If your table has columns "ID" and "NAME", then $row will be hash ref with keys "ID" and "NAME". See ``STATEMENT HANDLES'' below for more details on statement handles.
But now for a more formal approach:
use DBI; my $dsn = "DBI:MariaDB:$database"; my $dsn = "DBI:MariaDB:database=$database;host=$hostname"; my $dsn = "DBI:MariaDB:database=$database;host=$hostname;port=$port"; my $dsn = "DBI:MariaDB:database=$database;mariadb_socket=$socket"; my $dbh = DBI->connect($dsn, $user, $password);
The database is not a required attribute, but please note that MariaDB and MySQL has no such thing as a default database. If you don't specify the database at connection time your active database will be null and you'd need to prefix your tables with the database name; i.e. "SELECT * FROM mydb.mytable".
This is similar to the behavior of the "mariadb" or "mysql" command line client. Also, "SELECT DATABASE()" will return the current database active for the handle.
Should the MariaDB or MySQL server be running on a non-standard port number, you may explicitly state the "port number" to connect to in the host argument, by concatenating the "hostname" and "port number" together separated by a colon (":") character or by using the port argument.
To connect to a MariaDB or MySQL server on localhost using TCP/IP, you must specify the host as 127.0.0.1 with the optional port, e.g. 3306.
When connecting to a MariaDB or MySQL Server with IPv6, a bracketed IPv6 address should be used. Example DSN:
my $dsn = 'DBI:MariaDB:;host=[1a12:2800:6f2:85::f20:8cf];port=3306';
UPDATE t SET id = 1 WHERE id = 1;
then the MariaDB or MySQL engine will always return 0, because no rows have changed. With mariadb_client_found_rows however, it will return the number of rows that have an id 1, as some people are expecting. At least for compatibility to other engines.
By default mariadb_client_found_rows is enabled.
my $dsn = 'DBI:MariaDB:test;mariadb_read_default_file=/home/joe/my.cnf'; my $dbh = DBI->connect($dsn, $user, $password);
The option mariadb_read_default_group can be used to specify the default group in the config file: Usually this is the "client" group, but see the following example:
[client] host=localhost [perl] host=perlhost
(Note the order of the entries! The example won't work, if you reverse the "[client]" and "[perl]" sections!)
If you read this config file, then you'll be typically connected to "localhost". However, by using
my $dsn = 'DBI:MariaDB:test;mariadb_read_default_group=perl;' . 'mariadb_read_default_file=/home/joe/my.cnf'; my $dbh = DBI->connect($dsn, $user, $password);
you'll be connected to "perlhost". Note that if you specify a default group and do not specify a file, then the default config files will all be read. See the documentation of the C function "mysql_options()" for details.
my $dsn = 'DBI:MariaDB:database=test;' . 'mariadb_socket=/var/run/mysqld/mysqld.sock';
Usually there's no need for this option, unless you are using another location for the socket than that built into the client.
When enabling SSL encryption you should set also other SSL options, at least mariadb_ssl_ca_file or mariadb_ssl_ca_path.
my $dsn = 'DBI:MariaDB:database=test;host=hostname;port=3306;' . 'mariadb_ssl=1;mariadb_ssl_verify_server_cert=1;' . 'mariadb_ssl_ca_file=/path/to/ca_cert.pem';
This means that your communication with the server will be encrypted.
When set MariaDB or MySQL server certificate is checked that it is signed by some CA certificate in the list. Common Name value is not verified unless mariadb_ssl_verify_server_cert is enabled.
When set MariaDB or MySQL server certificate is checked that it is signed by some CA certificate in the list. Common Name value is not verified unless mariadb_ssl_verify_server_cert is enabled.
Please note that this option is supported only if your MariaDB or MySQL client was compiled with OpenSSL library, and not with default yaSSL library.
Verification of the host name is disabled by default.
mariadb_ssl_cipher=AES128-SHA mariadb_ssl_cipher=DHE-RSA-AES256-SHA:AES128-SHA
Due to The BACKRONYM <http://backronym.fail/> and The Riddle <https://riddle.link/> vulnerabilities in libmariadb and libmysqlclient libraries, enforcement of SSL encryption was not possible and therefore "mariadb_ssl_optional=1" was effectively set for old DBD::mysql driver prior DBD::MariaDB fork was created. DBD::MariaDB with "mariadb_ssl=1" could refuse connection to MariaDB or MySQL server if underlying libmariadb or libmysqlclient library is vulnerable. Option mariadb_ssl_optional can be used to make SSL connection vulnerable.
This default behavior may change in the future.
To use server side prepared statements, all you need to do is set the variable mariadb_server_prepare in the connect:
my $dbh = DBI->connect( 'DBI:MariaDB:database=test;host=localhost;mariadb_server_prepare=1', 'user', 'password', { RaiseError => 1, PrintError => 0 }, );
or:
my $dbh = DBI->connect( 'DBI:MariaDB:database=test;host=localhost', 'user', 'password', { RaiseError => 1, PrintError => 0, mariadb_server_prepare => 1 }, );
There are many benefits to using server side prepare statements, mostly if you are using SQL statements with placeholders or performing many inserts because of that fact that a single statement is prepared to accept multiple insert values.
Please note that MariaDB or MySQL server cannot prepare or execute some prepared statements. In this case DBD::MariaDB fallbacks to normal non-prepared statement and tries again.
Useful when you want to be sure that the statement is going to be executed as server side prepared. Error message and code in case of failure is propagated back to DBI.
This default behavior may change in the future.
Example:
use DBI; my $datadir = '/var/lib/mysql/'; my $langdir = '/usr/share/mysql/english'; my $dsn = 'DBI:MariaDB:host=embedded;database=test;' . "mariadb_embedded_options=--datadir=$datadir,--language=$langdir"; my $dbh = DBI->connect($dsn, undef, undef);
This would start embedded server with language directory $langdir, database directory $datadir and connects to database "test". Embedded server does not have to be supported by configured MariaDB or MySQL library. In that case "DBI->connect()" returns an error.
Example:
my $dsn = 'DBI:MariaDB:host=embedded;database=test;' . 'mariadb_embedded_groups=embedded_server,common';
You can then later read these attributes from the performance schema tables which can be quite helpful for profiling your database or creating statistics. You'll have to use both server and client at least in version MariaDB 10.0.5 or MySQL 5.6 to leverage this feature. It is a good idea to provides additional "program_name" attribute.
my $dbh= DBI->connect($dsn, $user, $password, { AutoCommit => 0, mariadb_conn_attrs => { program_name => $0, foo => 'bar', wiz => 'bang' }, });
Now you can select the results from the performance schema tables. You can do this in the same session, but also afterwards. It can be very useful to answer questions like which script sent this query?
my $results = $dbh->selectall_hashref( 'SELECT * FROM performance_schema.session_connect_attrs', 'ATTR_NAME' );
This returns:
$result = { '_client_name' => { 'ATTR_VALUE' => 'libmysql', 'ATTR_NAME' => '_client_name', 'ORDINAL_POSITION' => '1', 'PROCESSLIST_ID' => '3', }, '_client_version' => { 'ATTR_VALUE' => '5.6.24', 'ATTR_NAME' => '_client_version', 'ORDINAL_POSITION' => '7', 'PROCESSLIST_ID' => '3', }, '_os' => { 'ATTR_VALUE' => 'osx10.8', 'ATTR_NAME' => '_os', 'ORDINAL_POSITION' => '0', 'PROCESSLIST_ID' => '3', }, '_pid' => { 'ATTR_VALUE' => '59860', 'ATTR_NAME' => '_pid', 'ORDINAL_POSITION' => '2', 'PROCESSLIST_ID' => '3', }, '_platform' => { 'ATTR_VALUE' => 'x86_64', 'ATTR_NAME' => '_platform', 'ORDINAL_POSITION' => '4', 'PROCESSLIST_ID' => '3', }, 'foo' => { 'ATTR_NAME' => 'foo', 'ATTR_VALUE' => 'bar', 'ORDINAL_POSITION' => '6', 'PROCESSLIST_ID' => '3', }, 'program_name' => { 'ATTR_VALUE' => './foo.pl', 'ATTR_NAME' => 'program_name', 'ORDINAL_POSITION' => '5', 'PROCESSLIST_ID' => '3', }, 'wiz' => { 'ATTR_VALUE' => 'bang', 'ATTR_NAME' => 'wiz', 'ORDINAL_POSITION' => '3', 'PROCESSLIST_ID' => '3', }, };
use DBI; my @dsns = DBI->data_sources('MariaDB', { host => $hostname, port => $port, user => $username, password => $password, ... });
Returns a list of all databases in dsn format suitable for connect method, managed by the MariaDB or MySQL server. It accepts all attributes from connect method.
my $errno = $dbh->{'mariadb_errno'}; my $error = $dbh->{'mariadb_error'}; my $hostinfo = $dbh->{'mariadb_hostinfo'}; my $info = $dbh->{'mariadb_info'}; my $insertid = $dbh->{'mariadb_insertid'}; my $protoinfo = $dbh->{'mariadb_protoinfo'}; my $serverinfo = $dbh->{'mariadb_serverinfo'}; my $ssl_cipher = $dbh->{'mariadb_ssl_cipher'}; my $stat = $dbh->{'mariadb_stat'}; my $thread_id = $dbh->{'mariadb_thread_id'};
These correspond to "mysql_errno()", "mysql_error()", "mysql_get_host_info()", "mysql_info()", "mysql_insert_id()", "mysql_get_proto_info()", "mysql_get_server_info()", "mysql_stat()", "mysql_get_ssl_cipher()" and "mysql_thread_id()" respectively.
Portable DBI applications should not use them. Instead they should use standard DBI methods: "$dbh->err()" and "$dbh->errstr()" for error number and string, "$dbh->get_info($GetInfoType{SQL_SERVER_NAME})" for server host name, "$dbh->get_info($GetInfoType{SQL_DBMS_NAME})" and "$dbh->get_info($GetInfoType{SQL_DBMS_VER})" for server database name and version, "$dbh->last_insert_id()" or "$sth->last_insert_id()" for insert id.
print "$dbh->{mariadb_clientinfo}\n"; 5.2.0-MariaDB print "$dbh->{mariadb_clientversion}\n"; 50200
Portable DBI applications should not be interested in version of underlying client library. DBD::MariaDB is there to hide any possible incompatibility and works correctly with any available version.
print "$dbh->{mariadb_serverversion}\n"; 50200
Portable DBI applications should use "$dbh->get_info($GetInfoType{SQL_DBMS_NAME})" and "$dbh->get_info($GetInfoType{SQL_DBMS_VER})" for server database name and version instead.
my $ssl_cipher = $dbh->{mariadb_ssl_cipher}; if (defined $ssl_cipher) { print "Connection with server is encrypted with cipher: $ssl_cipher\n"; } else { print "Connection with server is not encrypted\n"; }
my $info_hashref = $dbh->{mariadb_dbd_stats};
DBD::MariaDB keeps track of some statistics in the mariadb_dbd_stats attribute. The following stats are being maintained:
The DBD::MariaDB driver also supports the following attributes of database handles (read/write):
It is also possible to set the default value of the mariadb_auto_reconnect attribute for the $dbh by passing it in the "\%attr" hash for "DBI->connect".
$dbh->{mariadb_auto_reconnect} = 1;
or
my $dbh = DBI->connect($dsn, $user, $password, { mariadb_auto_reconnect => 1, });
Note that if you are using a module or framework that performs reconnections for you (for example DBIx::Connector in fixup mode), this value must be set to 0.
It is possible to set the default value of the mariadb_use_result attribute for the $dbh via the DSN:
my $dbh = DBI->connect('DBI:MariaDB:test;mariadb_use_result=1', $user, $pass);
You can also set it after creation of the database handle:
$dbh->{mariadb_use_result} = 0; # disable $dbh->{mariadb_use_result} = 1; # enable
You can also set or unset the mariadb_use_result setting on your statement handle, when creating the statement handle or after it has been created. See ``STATEMENT HANDLES''.
CAVEAT: Even though you can insert an integer value into a character column, if this column is indexed, if you query that column with the integer value not being quoted, it will not use the index:
MariaDB [test]> explain select * from test where value0 = '3' \G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: test type: ref possible_keys: value0 key: value0 key_len: 13 ref: const rows: 1 Extra: Using index condition 1 row in set (0.00 sec) MariaDB [test]> explain select * from test where value0 = 3 -> \G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: test type: ALL possible_keys: value0 key: NULL key_len: NULL ref: NULL rows: 6 Extra: Using where 1 row in set (0.00 sec)
See bug: <https://rt.cpan.org/Public/Bug/Display.html?id=43822>
mariadb_bind_type_guessing can be turned on via
- through DSN
my $dbh = DBI->connect('DBI:MariaDB:test', 'username', 'pass', { mariadb_bind_type_guessing => 1 });
- OR after handle creation
$dbh->{mariadb_bind_type_guessing} = 1;
See the bug report: <https://rt.cpan.org/Public/Bug/Display.html?id=46308>
mariadb_no_autocommit_cmd can be turned on when creating the database handle:
my $dbh = DBI->connect('DBI:MariaDB:test', 'username', 'pass', { mariadb_no_autocommit_cmd => 1 });
or using an existing database handle:
$dbh->{mariadb_no_autocommit_cmd} = 1;
$dbh->{mariadb_max_allowed_packet} = 32*1024*1024; # limit max size to 32MB
Documentation for some DBD::MariaDB methods of database handles:
my $rc = $dbh->ping();
use DBI::Const::GetInfoType; print $dbh->get_info($GetInfoType{SQL_DBMS_NAME}); MariaDB print $dbh->get_info($GetInfoType{SQL_DBMS_VER}); 10.01.2600 print $dbh->get_info($GetInfoType{SQL_SERVER_NAME}); Localhost via UNIX socket
my $numFields = $sth->{NUM_OF_FIELDS};
Note, that most attributes are valid only after a successful execute. An "undef" value will returned otherwise. The most important exception is the mariadb_use_result attribute.
To set the mariadb_use_result attribute on statement handle $sth, use either of the following:
my $sth = $dbh->prepare($sql, { mariadb_use_result => 1});
or
my $sth = $dbh->prepare($sql); $sth->{mariadb_use_result} = 1;
Column dependent attributes, for example NAME, the column names, are returned as a reference to an array. The array indices are corresponding to the indices of the arrays returned by fetchrow and similar methods. For example the following code will print a header of table names together with all rows:
my $sth = $dbh->prepare('SELECT * FROM t') or die 'Error: ' . $dbh->errstr() . "\n"; $sth->execute() or die 'Error: ' . $sth->errstr() . "\n"; my $names = $sth->{NAME}; my $numFields = $sth->{'NUM_OF_FIELDS'} - 1; for my $i ( 0..$numFields ) { printf('%s%s', $i ? ',' : '', $$names[$i]); } print "\n"; while (my $ref = $sth->fetchrow_arrayref()) { for my $i ( 0..$numFields ) { printf('%s%s', $i ? ',' : '', $$ref[$i]); } print "\n"; }
For portable applications you should restrict yourself to attributes with capitalized or mixed case names. Lower case attribute names are private to DBD::MariaDB. The attribute list includes:
Typically, you'd access the value via "$sth->{mariadb_insertid}". The value can also be accessed via "$dbh->{mariadb_insertid}" but this can easily produce incorrect results in case one database handle is shared.
Portable DBI applications should not use mariadb_insertid. Instead they should use DBI method "$dbh->last_insert_id()" or statement DBI method "$sth->last_insert_id()". Statement method was introduced in DBI version 1.642, but DBD::MariaDB implements it also for older DBI versions.
For string orientated variable types (char, varchar, text and similar types) both attributes return value in bytes. If you are interested in number of characters then instead of mariadb_length use "COLUMN_SIZE" via standard DBI method column_info and instead of mariadb_max_length issue SQL query "SELECT MAX(CHAR_LENGTH(...))". Example:
my $ci_sth = $dbh->column_info(undef, undef, $table, $column); my $ci_ref = $ci_sth->fetchall_arrayref({}); my $mariadb_char_length = $ci_ref->[0]->{COLUMN_SIZE}; my $mariadb_char_max_length = $dbh->selectrow_array(sprintf( 'SELECT MAX(CHAR_LENGTH(%s)) FROM %s', $dbh->quote_identifier($column), $dbh->quote_identifier($table), ));
MySQL's "utf8mb4" charset for the network communication is configured by "MYSQL_SET_CHARSET_NAME" libmariadb/libmysqlclient C library API which is a requirement to have working quote method and an emulated client side placeholders replacement.
Do not try to change network charset (e.g. via SQL command "SET NAMES" manually) to anything different then UTF-8 as it would confuse underlying C library and DBD::MariaDB would misbehave (e.g. would lead to broken/insecure quote method or an emulated client side placeholders replacement).
Using a non-UTF-8 charset for a column, table or database is fine because MariaDB or MySQL server automatically transforms the storage charset to the charset used by the network protocol ("utf8mb4"). Note that when DBD::MariaDB is connecting to the MariaDB or MySQL server it calls SQL command "SET character_set_server = 'utf8mb4'" to ensure that the default charset for new databases would be UTF-8. Beware that a default charset for new tables is set from a database charset.
In the case MySQL server does not support MySQL's "utf8mb4" charset for a network protocol then DBD::MariaDB would try to use MySQL's "utf8" charset which is a subset of UTF-8 encoding restricted to the 3 byte UTF-8 sequences. Support for MySQL's "utf8mb4" charset was introduced in MySQL server version 5.5.3.
When fetching data from MariaDB and MySQL servers, DBD::MariaDB treats all fields marked with MySQL's charset "utf8mb4" (and also "utf8") as Unicode strings. Everything else is treated as binary byte oriented buffers. Therefore, the only difference is that UTF-8 fields are automatically decoded to Unicode. Binary blob fields remain untouched and corresponding Perl scalars would contain just ordinals 0..255 (classic sequence of bytes). Unicode string scalars would contain sequence of Unicode code points.
There is a small problem with input data, more preciously with SQL statements and their bind parameters. By definition a SQL statement is a string and therefore it is expected and handled by DBD::MariaDB as a Unicode string (not byte oriented buffer). There is no way to treat a SQL statement as a binary, but this is not a problem. All SQL commands are encoded in ASCII and all ASCII characters are invariants in UTF-8 (have the same representation as a sequence of Unicode code points and also when UTF-8 encoded in a byte buffer). For the remaining part of a SQL statement, placeholders with bind parameters can and should be used.
Moreover, DBI API for do, execute and all select* methods binds all parameters as "SQL_VARCHAR" type. Currently it is an API limitation which does not allow one to specify the bind type. Varchar is a string and so DBD::MariaDB treats all of them as Unicode strings.
The only way how to specify a type in DBI is via the bind_param method. Its third argument takes "SQL_*" constant which defines a type for the passed bind parameter.
Following type constants are treated as binary by DBD::MariaDB: "SQL_BIT", "SQL_BLOB", "SQL_BINARY", "SQL_VARBINARY", "SQL_LONGVARBINARY".
This approach of handling binary data was implemented in DBD::MariaDB because it does not violate how Perl's Unicode model is working, follows exactly DBI API documentation, and, more importantly, is how other DBI drivers (including DBD::Pg and DBD::SQLite) in their recent versions work. This ensures good compatibility for Perl applications which use multiple database backends and several DBI drivers.
Please note that the old DBD::mysql driver in version 4.041 works differently and has completely broken Unicode support.
To illustrate the usage, see the following example:
# Prepare statement my $sth = $dbh->prepare( 'INSERT INTO users (id, name, picture) VALUES (?, ?, ?)' ); # Bind number, 7-bit ASCII values are always in Unicode and binary context $sth->bind_param(1, 10); # Bind name, may contains Unicode character, in this case U+00E9 $sth->bind_param(2, "Andr\x{E9}"); # Bind picture, it is a sequence of binary bytes, not Unicode code points $sth->bind_param(3, "\x{D8}\x{A0}\x{39}\x{F8}", DBI::SQL_BINARY); # Execute statement with bind parameters $sth->execute();
Explanation: In this case number 10 and name "Andr\x{E9}" would be automatically encoded from Perl Unicode string scalars to MySQL's "utf8mb4" network charset and picture would not be touched as it was bound with the "DBI::SQL_BINARY" type. Note that 7-bit ASCII values are invariants in UTF-8, they have the same representations in UTF-8, so both the encoding and decoding operations are just identity functions.
This is the preferred and safe way how to work with binary data. It is also supported by other DBI drivers, including DBD::Pg and DBD::SQLite (see above).
In DBD::MariaDB, there's another specific way how to create a SQL statement with binary data: to call the quote method while specifying a binary type. This method takes a bind parameter and properly quotes + escapes it. For binary types it converts argument to MySQL's HEX syntax ("X'...'") which is a pure 7-bit ASCII and therefore invariant for UTF-8. See the following example:
my $param1 = 10; my $param2 = "Andr\x{E9}"; my $param3 = "\x{D8}\x{A0}\x{39}\x{F8}"; my $query = 'INSERT INTO users (id, name, picture) VALUES (' . $dbh->quote($param1) . ' ,' . $dbh->quote($param2) . ' ,' . $dbh->quote($param3, DBI::SQL_BINARY) . ')'; $dbh->do($query);
The first two parameters are quoted and escaped for a later UTF-8 encoding (to MySQL's "utf8mb4" charset) and the third parameter is quoted and escaped as a binary buffer to MySQL's HEX syntax for binary blobs.
This method is not recommended, because quoting, escaping and similar methods can easily get written incorrectly and lead to SQL injections and other security problems.
$dbh->{AutoCommit} = 0;
or
$dbh->{AutoCommit} = 1;
then the driver will set the MariaDB or MySQL server variable autocommit to 0 or 1, respectively. Switching from 0 to 1 will also issue a "COMMIT", following the DBI specifications.
$dbh->rollback(); $dbh->commit();
will issue the commands "ROLLBACK" and "COMMIT", respectively. A "ROLLBACK" will also be issued if AutoCommit mode is off and the database handles DESTROY method is called. Again, this is following the DBI specifications.
Given the above, you should note the following:
$dbh->{AutoCommit} = 0; if ($dbh->{AutoCommit}) { # An error occurred! }
The basic usage of multiple result sets is
do { while (my @row = $sth->fetchrow_array()) { do stuff; } } while ($sth->more_results);
An example would be:
$dbh->do('drop procedure if exists someproc') or print $DBI::errstr; $dbh->do('create procedure someproc() deterministic begin declare a,b,c,d int; set a=1; set b=2; set c=3; set d=4; select a, b, c, d; select d, c, b, a; select b, a, c, d; select c, b, d, a; end' ) or die "$DBI::err: $DBI::errstr"; my $sth = $dbh->prepare('call someproc()') or die "$DBI::err: $DBI::errstr"; $sth->execute() or die "$DBI::err: $DBI::errstr"; my $i=0; do { print "\nRowset ".++$i."\n---------------------------------------\n\n"; foreach my $colno (0..$sth->{NUM_OF_FIELDS}-1) { print $sth->{NAME}->[$colno]."\t"; } print "\n"; while (my @row = $sth->fetchrow_array()) { foreach $field (0..$#row) { print $row[$field]."\t"; } print "\n"; } } while ($sth->more_results);
The obvious question is: Are the C libraries thread safe? In the case of MySQL the answer is yes, since MySQL 5.5 it is. Older versions C library needs to be compiled with "--with-thread-safe-client" or "--enable-thread-safe-client" configure options.
Here's an example of how to use the asynchronous query interface:
use feature 'say'; $dbh->do('SELECT SLEEP(10)', { mariadb_async => 1 }); until($dbh->mariadb_async_ready()) { say 'not ready yet!'; sleep 1; } my $rows = $dbh->mariadb_async_result();
The first incarnation of DBD::mysql was developed by Alligator Descartes, who was also aided and abetted by Gary Shea, Andreas König and Tim Bunce.
The current incarnation of DBD::mysql was written by Jochen Wiedmann, then numerous changes and bug-fixes were added by Rudy Lippan. Next, prepared statement support was added by Patrick Galbraith and Alexy Stroganov (who also solely added embedded server support).
Since 2004 DBD::mysql has been maintained by Patrick Galbraith (patg@patg.net), and since 2013 with the great help of Michiel Beijen (michiel.beijen@gmail.com), along with the entire community of Perl developers who keep sending patches to help continue improving DBD::mysql.
In 2018 unreleased version 4.042_01 of DBD::mysql was forked and DBD::MariaDB was created to fix long standing Unicode bugs and MariaDB support. Currently it is developed in GoodData and maintained by Pali (pali@cpan.org).
<https://github.com/gooddata/DBD-MariaDB>
Either fork this repository and produce a branch with your changeset that the maintainer can merge to his tree, or create a diff with git. The maintainer is more than glad to take contributions from the community as many features and fixes from DBD::MariaDB have come from the community.
To subscribe to this list, send an email to
"dbi-users-subscribe@perl.org" <mailto:dbi-users-subscribe@perl.org>
Mailing list archives are at
<http://groups.google.com/group/perl.dbi.users?hl=en&lr=>
where documentation, pointers to the mailing lists and mailing list archives and pointers to the most current versions of the modules can be used.
Information on the DBI interface itself can be gained by typing:
perldoc DBI
Information on DBD::MariaDB specifically can be gained by typing:
perldoc DBD::MariaDB
(this will display the document you're currently reading)
<https://github.com/gooddata/DBD-MariaDB/issues>
In past for DBD::mysql, MySQL/Sun/Oracle responded to bugs and assisted in fixing bugs which many thanks should be given for their help! This driver is outside the realm of the numerous components they support, and the maintainer and community solely support DBD::mysql and DBD::MariaDB.