Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-19 Thread Vincent Vega
Dennis ,
Thanks a lot for this detailed explnation. I will follow your suggestions.
Bottom line, in terms of memory allocations, even if I get SQLITE_CONSTRAINT ,I 
should release the memory I got at sqlite3_mprintf() by calling sqlite3_free()  
and also release the memory I got at sqlite3_prepare_v2() by calling 
sqlite3_finalize() .




- Original Message 
From: Dennis Cote <[EMAIL PROTECTED]>
To: General Discussion of SQLite Database <sqlite-users@sqlite.org>
Sent: Wednesday, March 19, 2008 12:06:04 AM
Subject: Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

Vincent Vega wrote:
> Well , since I do need to avoid a case where duplicated tags are
> inserted ,I have added a treatment to the case of SQLITE_CONSTRAINT.

OK, but what you have shown doesn't do anything useful. If your Tag 
values must really be unique, then it is an error to insert a duplicate 
Tag value. There is really nothing to do except possibly report the 
error. If you believe the Tag value that are being inserted are supposed 
to be unique then you might want to rollback your transaction on a 
constraint error (which is what you get when you break the uniqueness 
constraint on the Tag column).

> I am just curious whether I need to call sqlite3_finalize(Statement)
> after sqlite3_step(Statement) returns SQLITE_CONSTRAINT so that the
> memory that was allocated at sqlite3_mprintf  be released ?
> 

Yes and no. You do need to finalize the statement to release resources 
allocated when the statement was prepared. In addition, you also need to 
call sqlite3_free() to release the memory allocated by 
sqlite3_mprintf(). These are separate allocations and require separate 
release calls.

> Here are the table defenitions :
> CREATE TABLE 'Inventory' (
> 'TagIndex' integer PRIMARY KEY,
> 'Tag' varchar(12) NOT NULL,
> ) ;
> CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);
> 

The word unique between create and index is what causes the constraint 
error you are seeing. This only happens if you insert a duplicate Tag value.

> My code looks like this:
> 
> query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");

This allocates memory and saves a pointer to it in query.

> rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);

This allocates a statement and saves a pointer to it in Statement.

> if (rc!=SQLITE_OK)
>error_print();
> 
> sqlite3_exec(db,"BEGIN;",NULL,NULL,);
> for (i=1;i<500;i ++)
> {
>rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);

This binds the i'th value in the array list to the parameter that will 
be inserted into the Tag column.

>if (rc!=SQLITE_OK)
>error_print();
>rc=sqlite3_step(Statement);

This executes the statement. Either inserting the value and assigning a 
new TagIndex and then returning SQLITE_DONE, or doing nothing and 
returning SQLITE_CONSTRAINT.

>if (rc!=SQLITE_DONE)
>{
>  if (rc==SQLITE_CONSTRAINT )  
>{

You end up here if your list has duplicate entries.

>  query = sqlite3_mprintf("Insert into Inventory (Tag) values 
> (?)");

This overwrites the pointer stored in query. The previous value is lost 
and memory is leaked. You must use a different pointer or call 
sqlite3_free() to release the old value first.

>  rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);

This overwrites the statement pointer stored in Statement. The previous 
value is lost and memory is leaked. You must use a different pointer or 
call sqlite3_finalize() to release the old value first.

>  if (rc!=SQLITE_OK)
>error_print();
>}
>error_print();
>}
>sqlite3_reset(Statement) ;
> }
> sqlite3_finalize(Statement) ;

This releases the statement allocated by prepare above.

> 
> sqlite3_exec(db,"END;",NULL,NULL,) ;

The string query is never released. Call sqlite3_free() to do so.

I'm not sure what you are trying to accomplish when you detect the 
SQLITE_CONSTRAINT error returned from sqlite3_step(). Re-preparing the 
same SQL statement again will not correct anything. Your list has real 
duplicate values, you have told SQLite not to accept duplicate values, 
and it has told you that you have tried to enter a duplicate value. You 
really need to ignore the duplicate and continue (possibly reporting the 
  duplicate), or abort, fix your list to remove the duplicates, and then 
try again later.


This code should probably be changed to something like this depending 
upon exactly what you want to do if your list contains duplicates:

query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
if (rc!=SQLITE_OK)
error_print();

int abort = 0;
sqlite3_exec(db,"BEGIN;",NULL,NULL,);
for (i=1;i<500;i ++)
{
rc=sqlite3_bind_text(Statem

Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-18 Thread Jay A. Kreibich
On Tue, Mar 18, 2008 at 04:06:04PM -0600, Dennis Cote scratched on the wall:
> Vincent Vega wrote:

> > query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
> 
> This allocates memory and saves a pointer to it in query.

  My question is why use "sqlite3_mprintf()" at all?  You're not
  actually using any of the formatting functionality of _mprintf, only
  passing a string literal which is then copied into a newly allocated
  string.  Since you're not modifying the string, there is no reason to
  make a copy of it.  The string literal you're passing to _mprintf is
  going to be embedded into the application's memory space by the compiler.
  There is no reason to not just pass the literal (or a reference to it)
  directly to _prepare, which expects a const char* anyways.

  Most compilers are even smart enough to combine multiple equivalent
  string literals into a single reference, but just in case your compiler
  is not, you can just setup a global var like this...

  const char sql_insertInventory[] = "Insert into Inventory (Tag) "

  ...and then reference the global var any time you need to reference the
  actual query string.  I tend to do this just to keep all the SQL string
  literals in one place, which helps with updates and changes.  It also
  allows me to use symbolic names in the code, which is usually a good
  thing.

  In this case (since you're not changing the query string), it seems to
  me that the best way to avoid leaking memory is not to allocate it in
  the first place.

> > rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);

  If you do have some reason for using _mprintf to allocate "query", you
  can/should de-allocate it right after this.  Once the statement is
  prepared, the literal SQL string is no longer needed.  The
  _prepare_v2 calls will keep a copy around, but everything I've seen
  leads me to believe that this is a private copy that is released with
  _finalize, and not something the user has to worry about.
  
  (right?)

   -j

-- 
Jay A. Kreibich < J A Y  @  K R E I B I.C H >

"'People who live in bamboo houses should not throw pandas.' Jesus said that."
   - "The Ninja", www.AskANinja.com, "Special Delivery 10: Pop!Tech 2006"
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-18 Thread Dennis Cote
Vincent Vega wrote:
> Well , since I do need to avoid a case where duplicated tags are
> inserted ,I have added a treatment to the case of SQLITE_CONSTRAINT.

OK, but what you have shown doesn't do anything useful. If your Tag 
values must really be unique, then it is an error to insert a duplicate 
Tag value. There is really nothing to do except possibly report the 
error. If you believe the Tag value that are being inserted are supposed 
to be unique then you might want to rollback your transaction on a 
constraint error (which is what you get when you break the uniqueness 
constraint on the Tag column).

> I am just curious whether I need to call sqlite3_finalize(Statement)
> after sqlite3_step(Statement) returns SQLITE_CONSTRAINT so that the
> memory that was allocated at sqlite3_mprintf  be released ?
> 

Yes and no. You do need to finalize the statement to release resources 
allocated when the statement was prepared. In addition, you also need to 
call sqlite3_free() to release the memory allocated by 
sqlite3_mprintf(). These are separate allocations and require separate 
release calls.

> Here are the table defenitions :
> CREATE TABLE 'Inventory' (
> 'TagIndex' integer PRIMARY KEY,
> 'Tag' varchar(12) NOT NULL,
> ) ;
> CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);
> 

The word unique between create and index is what causes the constraint 
error you are seeing. This only happens if you insert a duplicate Tag value.

> My code looks like this:
> 
> query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");

This allocates memory and saves a pointer to it in query.

> rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);

This allocates a statement and saves a pointer to it in Statement.

> if (rc!=SQLITE_OK)
> error_print();
> 
> sqlite3_exec(db,"BEGIN;",NULL,NULL,);
> for (i=1;i<500;i ++)
> {
> rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);

This binds the i'th value in the array list to the parameter that will 
be inserted into the Tag column.

> if (rc!=SQLITE_OK)
> error_print();
> rc=sqlite3_step(Statement);

This executes the statement. Either inserting the value and assigning a 
new TagIndex and then returning SQLITE_DONE, or doing nothing and 
returning SQLITE_CONSTRAINT.

> if (rc!=SQLITE_DONE)
> {
>  if (rc==SQLITE_CONSTRAINT )  
> {

You end up here if your list has duplicate entries.

>   query = sqlite3_mprintf("Insert into Inventory (Tag) values 
> (?)");

This overwrites the pointer stored in query. The previous value is lost 
and memory is leaked. You must use a different pointer or call 
sqlite3_free() to release the old value first.

>   rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);

This overwrites the statement pointer stored in Statement. The previous 
value is lost and memory is leaked. You must use a different pointer or 
call sqlite3_finalize() to release the old value first.

>   if (rc!=SQLITE_OK)
> error_print();
> }
> error_print();
> }
> sqlite3_reset(Statement) ;
> }
> sqlite3_finalize(Statement) ;

This releases the statement allocated by prepare above.

> 
> sqlite3_exec(db,"END;",NULL,NULL,) ;

The string query is never released. Call sqlite3_free() to do so.

I'm not sure what you are trying to accomplish when you detect the 
SQLITE_CONSTRAINT error returned from sqlite3_step(). Re-preparing the 
same SQL statement again will not correct anything. Your list has real 
duplicate values, you have told SQLite not to accept duplicate values, 
and it has told you that you have tried to enter a duplicate value. You 
really need to ignore the duplicate and continue (possibly reporting the 
  duplicate), or abort, fix your list to remove the duplicates, and then 
try again later.


This code should probably be changed to something like this depending 
upon exactly what you want to do if your list contains duplicates:

query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
if (rc!=SQLITE_OK)
 error_print();

int abort = 0;
sqlite3_exec(db,"BEGIN;",NULL,NULL,);
for (i=1;i<500;i ++)
{
 rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);
 if (rc!=SQLITE_OK)
 error_print();
 rc=sqlite3_step(Statement);
 if (rc!=SQLITE_DONE)
 {
 // SQLITE_CONSTRAINT error
abort = 1;

// uncomment this line to report errors
error_print();

// comment this line to ignore errors
break;
 }
 sqlite3_reset(Statement) ;
}
sqlite3_finalize(Statement) ;
sqlite3_free(query);

if (abort)
 sqlite3_exec(db, "ROLLBACK", NULL, NULL, );
else
 sqlite3_exec(db,"COMMIT",NULL,NULL,) ;


HTH
Dennis Cote
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-18 Thread Vincent Vega
Well , since I do need to avoid a case where duplicated tags are inserted ,I 
have added a treatment to the case of SQLITE_CONSTRAINT.
 I am just curious whether I need to call sqlite3_finalize(Statement)  after 
sqlite3_step(Statement) returns SQLITE_CONSTRAINT 
so that the memory that was allocated at sqlite3_mprintf  be released ? 
 
  
Here are the table defenitions :
CREATE TABLE 'Inventory' (
'TagIndex' integer PRIMARY KEY,
'Tag' varchar(12) NOT NULL,
) ;
CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);

My code looks like this:

query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
if (rc!=SQLITE_OK)
error_print();

sqlite3_exec(db,"BEGIN;",NULL,NULL,);
for (i=1;i<500;i ++)
{
rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);
if (rc!=SQLITE_OK)
error_print();
rc=sqlite3_step(Statement);
if (rc!=SQLITE_DONE)
{
 if (rc==SQLITE_CONSTRAINT )  
{
  query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
  rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
  if (rc!=SQLITE_OK)
error_print();
}
error_print();
}
sqlite3_reset(Statement) ;
}
sqlite3_finalize(Statement) ;

sqlite3_exec(db,"END;",NULL,NULL,) ;

 
 
 
 
 
 
 
 
 


 
- Original Message 
From: Dennis Cote <[EMAIL PROTECTED]>
To: General Discussion of SQLite Database <sqlite-users@sqlite.org>
Sent: Monday, March 17, 2008 11:10:35 PM
Subject: Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

Vincent Vega wrote:
> Thanks a lot . Your explantion does make sence.
> I'll remove the UNIQUE index and see if it helps.
> 

You probably shouldn't remove the index, just remove the unique keyword 
from the create index statement.

create index InventoryIndex on Inventory (Tag);

If you have an existing database you can drop the old index and create 
the new index without losing any data.

HTH
Dennis Cote
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


  

Looking for last minute shopping deals?  
Find them fast with Yahoo! Search.  
http://tools.search.yahoo.com/newsearch/category.php?category=shopping
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-17 Thread Dennis Cote
Vincent Vega wrote:
> Thanks a lot . Your explantion does make sence.
> I'll remove the UNIQUE index and see if it helps.
> 

You probably shouldn't remove the index, just remove the unique keyword 
from the create index statement.

create index InventoryIndex on Inventory (Tag);

If you have an existing database you can drop the old index and create 
the new index without losing any data.

HTH
Dennis Cote
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-17 Thread Vincent Vega
Dennis ,
Thanks a lot . Your explantion does make sence.
I'll remove the UNIQUE index and see if it helps.

Vincent.


- Original Message 
From: Dennis Cote <[EMAIL PROTECTED]>
To: General Discussion of SQLite Database <sqlite-users@sqlite.org>
Sent: Monday, March 17, 2008 4:27:11 PM
Subject: Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

Vincent Vega wrote:
> Anyhow, as I said before the code works fine most of the times(I can
> insert 500 records to the table and read them correctly) but from time
> to time I get SQLITE_CONSTRAINT error code after the sqlite3_step.
> Any Idea why?
> 
> Here are the table defenitions :
> CREATE TABLE 'Inventory' (
> 'TagIndex' integer PRIMARY KEY,
> 'Tag' varchar(12) NOT NULL,
> ) ;
> 
> CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);
> 

Vincent,

You are almost certainly inserting the same value a second time into the 
Tag column. You have added a unique index to this column which will 
raise a constraint error if you try to insert a row that has the same 
value in that column as some other row.

If you don't really require that the Tag column data be unique for each 
row, then change your index to o normal index without the unique 
constraint.

HTH
Dennis Cote


___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


  

Never miss a thing.  Make Yahoo your home page. 
http://www.yahoo.com/r/hs
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-17 Thread Dennis Cote
Vincent Vega wrote:
> Anyhow, as I said before the code works fine most of the times(I can
> insert 500 records to the table and read them correctly) but from time
> to time I get SQLITE_CONSTRAINT error code after the sqlite3_step.
> Any Idea why?
> 
> Here are the table defenitions :
> CREATE TABLE 'Inventory' (
> 'TagIndex' integer PRIMARY KEY,
> 'Tag' varchar(12) NOT NULL,
> ) ;
> 
> CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);
> 

Vincent,

You are almost certainly inserting the same value a second time into the 
Tag column. You have added a unique index to this column which will 
raise a constraint error if you try to insert a row that has the same 
value in that column as some other row.

If you don't really require that the Tag column data be unique for each 
row, then change your index to o normal index without the unique 
constraint.

HTH
Dennis Cote


___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-16 Thread David Bicking
Hopefully not too obvious questions, but do all your tests use the same values 
in the list array?  What is the value of list[i] when you get the 
SQLITE_CONSTRAINT error?  Are you confirming that the value of list[i] is in 
fact not somewhere earlier in the array? Any chance a NULL is creeping in to 
list[i]?

Is the table empty before you rn the tests?

The code looks okay, so my gut instinct would be to look at the data being fed 
in to see if that is causing the problem.

David



--- On Sun, 3/16/08, Vincent Vega <[EMAIL PROTECTED]> wrote:

> From: Vincent Vega <[EMAIL PROTECTED]>
> Subject: Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step
> To: [EMAIL PROTECTED], "General Discussion of SQLite Database" 
> <sqlite-users@sqlite.org>
> Date: Sunday, March 16, 2008, 4:37 AM
> Sorry.. I didn't copy it correctly..
> Anyhow, as I said before the code works fine most of the
> times(I can insert 500 records to the table and read them
> correctly) but from time to time I get SQLITE_CONSTRAINT
> error code after the sqlite3_step.
> Any Idea why?
> 
> Here are the table defenitions :
> CREATE TABLE 'Inventory' (
> 'TagIndex' integer PRIMARY KEY,
> 'Tag' varchar(12) NOT NULL,
> ) ;
> 
> CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);
> 
> My code looks like this:
>  
> query = sqlite3_mprintf("Insert into Inventory (Tag)
> values (?)");
> rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
> if (rc!=SQLITE_OK)
> error_print();
> sqlite3_exec(db,"BEGIN;",NULL,NULL,);
> for (i=1;i<500;i ++)
> {
> rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);
> if (rc!=SQLITE_OK)
> error_print();
> rc=sqlite3_step(Statement);
> if (rc!=SQLITE_DONE)
> error_print();
> sqlite3_reset(Statement) ;
> }
> sqlite3_finalize(Statement) ;
>  
> sqlite3_exec(db,"END;",NULL,NULL,) ;
> 
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-16 Thread Vincent Vega
Sorry.. I didn't copy it correctly..
Anyhow, as I said before the code works fine most of the times(I can insert 500 
records to the table and read them correctly) but from time to time I get 
SQLITE_CONSTRAINT error code after the sqlite3_step.
Any Idea why?

Here are the table defenitions :
CREATE TABLE 'Inventory' (
'TagIndex' integer PRIMARY KEY,
'Tag' varchar(12) NOT NULL,
) ;

CREATE UNIQUE INDEX InventoryIndex ON Inventory (Tag);

My code looks like this:
 
query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
if (rc!=SQLITE_OK)
error_print();
sqlite3_exec(db,"BEGIN;",NULL,NULL,);
for (i=1;i<500;i ++)
{
rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);
if (rc!=SQLITE_OK)
error_print();
rc=sqlite3_step(Statement);
if (rc!=SQLITE_DONE)
error_print();
sqlite3_reset(Statement) ;
}
sqlite3_finalize(Statement) ;
 
sqlite3_exec(db,"END;",NULL,NULL,) ;


 
- Original Message 
From: Jay A. Kreibich <[EMAIL PROTECTED]>
To: General Discussion of SQLite Database <sqlite-users@sqlite.org>
Sent: Saturday, March 15, 2008 3:07:46 AM
Subject: Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

On Fri, Mar 14, 2008 at 04:09:50PM -0700, Vincent Vega scratched on the wall:


> for (i=1;500;i ++)
> {

  I can't say about your CONSTRAINT problem, but that's an infinite loop.
  And 1?  Seriously?




  Without a full description of the table and all the indexes on the
  table (and, if possible, real data values), it is difficult to say
  what the problem is.  CONSTRAINT issues are normally data issues,
  not code problems.

  -j

-- 
Jay A. Kreibich < J A Y  @  K R E I B I.C H >

"'People who live in bamboo houses should not throw pandas.' Jesus said that."
  - "The Ninja", www.AskANinja.com, "Special Delivery 10: Pop!Tech 2006"
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


  

Never miss a thing.  Make Yahoo your home page. 
http://www.yahoo.com/r/hs
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


Re: [sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-14 Thread Jay A. Kreibich
On Fri, Mar 14, 2008 at 04:09:50PM -0700, Vincent Vega scratched on the wall:


> for (i=1;500;i ++)
> {

  I can't say about your CONSTRAINT problem, but that's an infinite loop.
  And 1?  Seriously?




  Without a full description of the table and all the indexes on the
  table (and, if possible, real data values), it is difficult to say
  what the problem is.  CONSTRAINT issues are normally data issues,
  not code problems.

   -j

-- 
Jay A. Kreibich < J A Y  @  K R E I B I.C H >

"'People who live in bamboo houses should not throw pandas.' Jesus said that."
   - "The Ninja", www.AskANinja.com, "Special Delivery 10: Pop!Tech 2006"
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users


[sqlite] SQLITE_CONSTRAINT error after sqlite3_step

2008-03-14 Thread Vincent Vega
Hi all ,
I am trying to insert about 500 records to a table.
I have tested my code and it works fine (All 500 recoreds are put in the table 
in about 250 miliseconds) but from time time I get SQLITE_CONSTRAINT error code 
after the sqlite3_step (1 out of 7 times).
Any idea on how to prevent this ?
That's my code:
 
 
query = sqlite3_mprintf("Insert into Inventory (Tag) values (?)");
rc=sqlite3_prepare_v2(DB,query ,-1,,NULL);
if (rc!=SQLITE_OK)
error_print();
sqlite3_exec(db,"BEGIN;",NULL,NULL,);
for (i=1;500;i ++)
{
rc=sqlite3_bind_text(Statement,1,list[i],-1,NULL);
if (rc!=SQLITE_OK)
error_print();
rc=sqlite3_step(Statement);
if (rc!=SQLITE_DONE)
error_print();
sqlite3_reset(Statement) ;
}
sqlite3_finalize(Statement) ;
 
sqlite3_exec(db,"END;",NULL,NULL,) ;
 
Thanks in advance ,
Vincent.
 
 



Never miss a thing. Make Yahoo your homepage. 


  

Be a better friend, newshound, and 
know-it-all with Yahoo! Mobile.  Try it now.  
http://mobile.yahoo.com/;_ylt=Ahu06i62sR8HDtDypao8Wcj9tAcJ 
___
sqlite-users mailing list
sqlite-users@sqlite.org
http://sqlite.org:8080/cgi-bin/mailman/listinfo/sqlite-users