Query: dbd::csv
OS: debian
Section: 3pm
Format: Original Unix Latex Style Formatted with HTML and a Horizontal Scroll Bar
DBD::CSV(3pm) User Contributed Perl Documentation DBD::CSV(3pm)NAMEDBD::CSV - DBI driver for CSV filesSYNOPSISuse DBI; # See "Creating database handle" below $dbh = DBI->connect ("dbi:CSV:") or die "Cannot connect: $DBI::errstr"; # Simple statements $dbh->do ("CREATE TABLE a (id INTEGER, name CHAR(10))") or die "Cannot prepare: " . $dbh->errstr (); # Selecting $dbh->{RaiseError} = 1; my $sth = $dbh->prepare ("select * from foo"); $sth->execute; while (my @row = $sth->fetchrow_array) { print "id: $row[0], name: $row[1] "; } # Updates my $sth = $dbh->prepare ("UPDATE a SET name = ? WHERE id = ?"); $sth->execute ("DBI rocks!", 1); $sth->finish; $dbh->disconnect;DESCRIPTIONThe DBD::CSV module is yet another driver for the DBI (Database independent interface for Perl). This one is based on the SQL "engine" SQL::Statement and the abstract DBI driver DBD::File and implements access to so-called CSV files (Comma Separated Values). Such files are often used for exporting MS Access and MS Excel data. See DBI for details on DBI, SQL::Statement for details on SQL::Statement and DBD::File for details on the base class DBD::File. Prerequisites The only system dependent feature that DBD::File uses, is the "flock ()" function. Thus the module should run (in theory) on any system with a working "flock ()", in particular on all Unix machines and on Windows NT. Under Windows 95 and MacOS the use of "flock ()" is disabled, thus the module should still be usable. Unlike other DBI drivers, you don't need an external SQL engine or a running server. All you need are the following Perl modules, available from any CPAN mirror, for example http://search.cpan.org/ DBI The DBI (Database independent interface for Perl), version 1.00 or a later release DBD::File This is the base class for DBD::CSV, and it is part of the DBI distribution. As DBD::CSV requires version 0.38 or newer for DBD::File it effectively requires DBI version 1.611 or newer. SQL::Statement A simple SQL engine. This module defines all of the SQL syntax for DBD::CSV, new SQL support is added with each release so you should look for updates to SQL::Statement regularly. It is possible to run "DBD::CSV" without this module if you define the environment variable $DBI_SQL_NANO to 1. This will reduce the SQL support a lot though. See DBI::SQL::Nano for more details. Note that the test suite does not test in this mode! Text::CSV_XS This module is used to read and write rows in a CSV file. Installation Installing this module (and the prerequisites from above) is quite simple. The simplest way is to install the bundle: $ cpan Bundle::CSV Alternatively, you can name them all $ cpan Text::CSV_XS DBI DBD::CSV or even trust "cpan" to resolve all dependencies for you: $ cpan DBD::CSV If you cannot, for whatever reason, use cpan, fetch all modules from CPAN, and build with a sequence like: gzip -d < DBD-CSV-0.28.tgz | tar xf - (this is for Unix users, Windows users would prefer WinZip or something similar) and then enter the following: cd DBD-CSV-0.28 perl Makefile.PL make test If any tests fail, let us know. Otherwise go on with make install UNINST=1 Note that you almost definitely need root or administrator permissions. If you don't have them, read the ExtUtils::MakeMaker man page for details on installing in your own directories. ExtUtils::MakeMaker. Supported SQL Syntax All SQL processing for DBD::CSV is done by SQL::Statement. See SQL::Statement for more specific information about its feature set. Features include joins, aliases, built-in and user-defined functions, and more. See SQL::Statement::Syntax for a description of the SQL syntax supported in DBD::CSV. Table- and column-names are case insensitive unless quoted. Column names will be sanitized unless "raw_header" is true; Using DBD::CSV with DBI For most things, DBD-CSV operates the same as any DBI driver. See DBI for detailed usage. Creating a database handle (connect) Creating a database handle usually implies connecting to a database server. Thus this command reads use DBI; my $dbh = DBI->connect ("dbi:CSV:", "", "", { f_dir => "/home/user/folder", }); The directory tells the driver where it should create or open tables (a.k.a. files). It defaults to the current directory, so the following are equivalent: $dbh = DBI->connect ("dbi:CSV:"); $dbh = DBI->connect ("dbi:CSV:", undef, undef, { f_dir => "." }); $dbh = DBI->connect ("dbi:CSV:f_dir=."); We were told, that VMS might - for whatever reason - require: $dbh = DBI->connect ("dbi:CSV:f_dir="); The preferred way of passing the arguments is by driver attributes: # specify most possible flags via driver flags $dbh = DBI->connect ("dbi:CSV:", undef, undef, { f_schema => undef, f_dir => "data", f_ext => ".csv/r", f_lock => 2, f_encoding => "utf8", csv_eol => " ", csv_sep_char => ",", csv_quote_char => '"', csv_escape_char => '"', csv_class => "Text::CSV_XS", csv_null => 1, csv_tables => { info => { file => "info.csv" } }, RaiseError => 1, PrintError => 1, FetchHashKeyName => "NAME_lc", }) or die $DBI::errstr; but you may set these attributes in the DSN as well, separated by semicolons. Pay attention to the semi-colon for "csv_sep_char" (as seen in many CSV exports from MS Excel) is being escaped in below example, as is would otherwise be seen as attribute separator: $dbh = DBI->connect ( "dbi:CSV:f_dir=$ENV{HOME}/csvdb;f_ext=.csv;f_lock=2;" . "f_encoding=utf8;csv_eol= ;csv_sep_char=\;;" . "csv_quote_char=";csv_escape_char=\;csv_class=Text::CSV_XS;" . "csv_null=1") or die $DBI::errstr; Using attributes in the DSN is easier to use when the DSN is derived from an outside source (environment variable, database entry, or configure file), whereas specifying entries in the attribute hash is easier to read and to maintain. Creating and dropping tables You can create and drop tables with commands like the following: $dbh->do ("CREATE TABLE $table (id INTEGER, name CHAR(64))"); $dbh->do ("DROP TABLE $table"); Note that currently only the column names will be stored and no other data. Thus all other information including column type (INTEGER or CHAR (x), for example), column attributes (NOT NULL, PRIMARY KEY, ...) will silently be discarded. This may change in a later release. A drop just removes the file without any warning. See DBI for more details. Table names cannot be arbitrary, due to restrictions of the SQL syntax. I recommend that table names are valid SQL identifiers: The first character is alphabetic, followed by an arbitrary number of alphanumeric characters. If you want to use other files, the file names must start with "/", "./" or "../" and they must not contain white space. Inserting, fetching and modifying data The following examples insert some data in a table and fetch it back: First, an example where the column data is concatenated in the SQL string: $dbh->do ("INSERT INTO $table VALUES (1, ". $dbh->quote ("foobar") . ")"); Note the use of the quote method for escaping the word "foobar". Any string must be escaped, even if it does not contain binary data. Next, an example using parameters: $dbh->do ("INSERT INTO $table VALUES (?, ?)", undef, 2, "It's a string!"); Note that you don't need to quote column data passed as parameters. This version is particularly well designed for loops. Whenever performance is an issue, I recommend using this method. You might wonder about the "undef". Don't wonder, just take it as it is. :-) It's an attribute argument that I have never used and will be passed to the prepare method as the second argument. To retrieve data, you can use the following: my $query = "SELECT * FROM $table WHERE id > 1 ORDER BY id"; my $sth = $dbh->prepare ($query); $sth->execute (); while (my $row = $sth->fetchrow_hashref) { print "Found result row: id = ", $row->{id}, ", name = ", $row->{name}; } $sth->finish (); Again, column binding works: The same example again. my $sth = $dbh->prepare (qq; SELECT * FROM $table WHERE id > 1 ORDER BY id; ;); $sth->execute; my ($id, $name); $sth->bind_columns (undef, $id, $name); while ($sth->fetch) { print "Found result row: id = $id, name = $name "; } $sth->finish; Of course you can even use input parameters. Here's the same example for the third time: my $sth = $dbh->prepare ("SELECT * FROM $table WHERE id = ?"); $sth->bind_columns (undef, $id, $name); for (my $i = 1; $i <= 2; $i++) { $sth->execute ($id); if ($sth->fetch) { print "Found result row: id = $id, name = $name "; } $sth->finish; } See DBI for details on these methods. See SQL::Statement for details on the WHERE clause. Data rows are modified with the UPDATE statement: $dbh->do ("UPDATE $table SET id = 3 WHERE id = 1"); Likewise you use the DELETE statement for removing rows: $dbh->do ("DELETE FROM $table WHERE id > 1"); Error handling In the above examples we have never cared about return codes. Of course, this is not recommended. Instead we should have written (for example): my $sth = $dbh->prepare ("SELECT * FROM $table WHERE id = ?") or die "prepare: " . $dbh->errstr (); $sth->bind_columns (undef, $id, $name) or die "bind_columns: " . $dbh->errstr (); for (my $i = 1; $i <= 2; $i++) { $sth->execute ($id) or die "execute: " . $dbh->errstr (); $sth->fetch and print "Found result row: id = $id, name = $name "; } $sth->finish ($id) or die "finish: " . $dbh->errstr (); Obviously this is tedious. Fortunately we have DBI's RaiseError attribute: $dbh->{RaiseError} = 1; $@ = ""; eval { my $sth = $dbh->prepare ("SELECT * FROM $table WHERE id = ?"); $sth->bind_columns (undef, $id, $name); for (my $i = 1; $i <= 2; $i++) { $sth->execute ($id); $sth->fetch and print "Found result row: id = $id, name = $name "; } $sth->finish ($id); }; $@ and die "SQL database error: $@"; This is not only shorter, it even works when using DBI methods within subroutines. DBI database handle attributes Metadata The following attributes are handled by DBI itself and not by DBD::File, thus they all work as expected: Active ActiveKids CachedKids CompatMode (Not used) InactiveDestroy Kids PrintError RaiseError Warn (Not used) The following DBI attributes are handled by DBD::File: AutoCommit Always on ChopBlanks Works NUM_OF_FIELDS Valid after "$sth->execute" NUM_OF_PARAMS Valid after "$sth->prepare" NAME NAME_lc NAME_uc Valid after "$sth->execute"; undef for Non-Select statements. NULLABLE Not really working. Always returns an array ref of one's, as DBD::CSV does not verify input data. Valid after "$sth->execute"; undef for non-Select statements. These attributes and methods are not supported: bind_param_inout CursorName LongReadLen LongTruncOk DBD-CSV specific database handle attributes In addition to the DBI attributes, you can use the following dbh attributes: DBD::File attributes f_dir This attribute is used for setting the directory where CSV files are opened. Usually you set it in the dbh and it defaults to the current directory ("."). However, it may be overridden in statement handles. f_ext This attribute is used for setting the file extension. f_schema This attribute allows you to set the database schema name. The default is to use the owner of "f_dir". "undef" is allowed, but not in the DSN part. my $dbh = DBI->connect ("dbi:CSV:", "", "", { f_schema => undef, f_dir => "data", f_ext => ".csv/r", }) or die $DBI::errstr; f_encoding This attribute allows you to set the encoding of the data. With CSV, it is not possible to set (and remember) the encoding on a column basis, but DBD::File now allows the encoding to be set on the underlying file. If this attribute is not set, or undef is passed, the file will be seen as binary. f_lock With this attribute you can specify a locking mode to be used (if locking is supported at all) for opening tables. By default, tables are opened with a shared lock for reading, and with an exclusive lock for writing. The supported modes are: 0 Force no locking at all. 1 Only shared locks will be used. 2 Only exclusive locks will be used. But see "KNOWN BUGS" in DBD::File. Text::CSV_XS specific attributes csv_eol csv_sep_char csv_quote_char csv_escape_char csv_class csv_csv The attributes csv_eol, csv_sep_char, csv_quote_char and csv_escape_char are corresponding to the respective attributes of the Text::CSV_XS object. You may want to set these attributes if you have unusual CSV files like /etc/passwd or MS Excel generated CSV files with a semicolon as separator. Defaults are "