Please pay attention to what huck and Corion have said. I say similar advice at Re^4: Perl DBI to MySQL LOAD_FILE. Inserting even all 170,568 records as a single transaction is no big deal - that is just fine. A commit operation is expensive, very expensive. When done properly simple single threaded code will take maybe a minute vs 4 hours.

Update: Performance Benchmark

To demonstrate my point that running a single transaction for all of the inserts will make a HUGE difference, I offer the following benchmark code that makes a test DB table with 170,568 records.

I used SQLite so that this can be run by anybody. If anything MySQL will be faster. I am using an ancient WinXP laptop.

Results:
Doing a commit after every insert = 4.9 hours! Doing a Single commit after all 170,568 inserts = 3 seconds!!! That is what I call a HUGE difference!

Since my laptop takes about 5 hours the OP's reported time of 4 hours sounds plausible. My guess is that a table creation like I show below will reduce the OP's execution time from 4 hours to 1-2 seconds. Nothing really fancy required, just some solid code.

#!/usr/bin/perl use strict; use warnings; use Data::Dumper; use DBI qw(:sql_types); my $dbfile = "./TestingInsert.sqlite"; if (-e $dbfile) {unlink $dbfile or die "Delete of $dbfile failed! $!\n +";} my $start_seconds = time(); my $dbh = DBI->connect("dbi:SQLite:dbname=$dbfile","","",{RaiseError = +> 1}) or die "Couldn't connect to database: " . DBI->errstr; $dbh->do ("CREATE TABLE test ( id integer PRIMARY KEY AUTOINCREMENT, version integer, jobnumber integer ); "); $dbh->do("BEGIN"); #running one transaction is needed for speed!!! import_data(); $dbh->do("COMMIT"); my $end_time = time(); print "Total elasped time: ", $end_time-$start_seconds, "\n"; sub import_data { my $jobnumber = 1; my $add = $dbh->prepare("INSERT INTO test ( version, jobnumber ) VALUES(?,?)"); while ($jobnumber < 170568) { $add->execute($jobnumber, $jobnumber++); #DBI insert } return; } __END__ Using a comitt for each insert: Total elasped time: 17833 => 297 min => 4.9 hours Using a single transaction for 170,568 inserts: Total elasped time: 3 seconds

In reply to Re^2: How to optimized mysql insert into table by Marshall
in thread How to optimized mysql insert into table by Mjpaddy

Title:
Use:  <p> text here (a paragraph) </p>
and:  <code> code here </code>
to format your post, it's "PerlMonks-approved HTML":



  • Posts are HTML formatted. Put <p> </p> tags around your paragraphs. Put <code> </code> tags around your code and data!
  • Titles consisting of a single word are discouraged, and in most cases are disallowed outright.
  • Read Where should I post X? if you're not absolutely sure you're posting in the right place.
  • Please read these before you post! —
  • Posts may use any of the Perl Monks Approved HTML tags:
    a, abbr, b, big, blockquote, br, caption, center, col, colgroup, dd, del, details, div, dl, dt, em, font, h1, h2, h3, h4, h5, h6, hr, i, ins, li, ol, p, pre, readmore, small, span, spoiler, strike, strong, sub, summary, sup, table, tbody, td, tfoot, th, thead, tr, tt, u, ul, wbr
  • You may need to use entities for some characters, as follows. (Exception: Within code tags, you can put the characters literally.)
            For:     Use:
    & &amp;
    < &lt;
    > &gt;
    [ &#91;
    ] &#93;
  • Link using PerlMonks shortcuts! What shortcuts can I use for linking?
  • See Writeup Formatting Tips and other pages linked from there for more info.