On Fri, Sep 16, 2005 at 10:41:59AM -0400, Doug Bloebaum wrote:
> On 9/15/05, Michael Fuhr <[EMAIL PROTECTED]> wrote:
> >
> > On Thu, Sep 15, 2005 at 06:48:59PM -0400, Robert Fitzpatrick wrote:
> > > Anyone know a package that can do this? Perferrably a Unix/Linux
> > > package.
> >
> > It would be trivial to write a script in a language like Perl to
> > read the first line of a file and generate a CREATE TABLE statement
> > from it, then issue a COPY command and send the rest of the file.
> > Determining the columns' data types would be a different matter:
> > if they weren't specified in the header then you'd have to guess
> > or perhaps make them all text.
>
>
> I've attached a sample implementation of Michael's suggestion.
I've attached what I hope is a slightly improved one :)
Cheers,
D
--
David Fetter [EMAIL PROTECTED] http://fetter.org/
phone: +1 510 893 6100 mobile: +1 415 235 3778
Remember to vote!
#!/usr/bin/perl -w
use DBI;
use Text::CSV_XS;
use File::Basename;
my $csv_file = shift or die "Usage: $0 <file.csv>\n";
my $fh; # Filehandle.
open $fh, '<', $csv_file # 3-argument open in case of name weirness.
or die "$0: Can't open $csv_file for read: $!\n";
my ($table_name) = fileparse($csv_file,qr{\..*});
$table_name = quote_odd_name($table_name);
warn "table_name=$table_name\n";
my $dbh = DBI->connect(
'dbi:Pg:dbname=dbname', 'user', 'pass', # should this be user input?
{ Auto_commit => 0 }
);
my $csv = Text::CSV_XS->new();
# create the table based on names from the header row
# columns will arbitrarily be of type TEXT, because VARCHAR(20)
# is a pretty silly limitation.
my $header = <$fh>;
$csv->parse($header) or die "$0: parse of header row failed\n";
my @columns = $csv->fields();
my $sql = "CREATE TABLE $table_name (\n "
. join(",\n ", map {quote_odd_name($_).' TEXT'} @columns)
. "\n)";
warn "\n$sql\n";
$dbh->do($sql);
# add rows of data using COPY
$dbh->do("COPY $table_name FROM STDIN WITH DELIMITER AS ','");
my $row_count = 0;
while(<$fh>) {
$dbh->pg_putline($_);
$row_count++;
}
close $fh;
$dbh->pg_endcopy;
$dbh->commit;
$dbh->disconnect;
warn "$0: Added $row_count rows to $table_name\n";
sub quote_odd_name {
my $name = shift;
my $sth = $dbh->prepare_cached('SELECT quote_ident(?)');
$sth->execute($name);
my $row = $sth->fetchrow_hashref;
$sth->finish;
return $row->{quote_ident};
}
---------------------------(end of broadcast)---------------------------
TIP 5: don't forget to increase your free space map settings