473,387 Members | 1,834 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,387 software developers and data experts.

Statment too long or too complex

Hi all.

I'm currently coping with a problem on which I hope you could shed some
light.
Imagine the following:
I have table in DB2 8.1 (.5) which is defined as:
table test {
t1 smallint,
t2 smallint,
t3 smallint,
t4 smallint,
t5 smallint,
t6 decimal,
t7 decimal,
t8 decimal,
t9 decimal,
t10 decimal,
t11 decimal,
t12 timestamp
}

No triggers, no indexes, no constraints.

Now, I insert 370 rows (in one statement) (insert .. (), (), ())
Next, I get an error stating "Statement too long or too complex (sql code
101))
Not too strange, could be some internal limitation.

But next, I drop the table and recreate it, but instead of using
smallints, I use integers (4bytes in stead of 2).

Now, when I insert, no problem.
Strange, eh?

But wait, there's more.
When I create the same table again, but with bigints in stead of integers.
Again the 101 error.

The strange part is that integer lays between smallint and bigint when it
comes to memory used.

Trial-and-error revealed that with smallints, I could only insert 276 rows.

Is this solved by APAR? (currently using fp5).
Does anyone know what this is all about? Is this a bug, a feature,
something I missing here?

Help is greatly appreciated.
Greetings,

-R-

Nov 12 '05 #1
8 5205
J.Haan wrote:
Hi all.

I'm currently coping with a problem on which I hope you could shed some
light.
Imagine the following:
I have table in DB2 8.1 (.5) which is defined as:
table test {
t1 smallint,
t2 smallint,
t3 smallint,
t4 smallint,
t5 smallint,
t6 decimal,
t7 decimal,
t8 decimal,
t9 decimal,
t10 decimal,
t11 decimal,
t12 timestamp
}

No triggers, no indexes, no constraints.

Now, I insert 370 rows (in one statement) (insert .. (), (), ())
Next, I get an error stating "Statement too long or too complex (sql code
101))
Not too strange, could be some internal limitation.

But next, I drop the table and recreate it, but instead of using
smallints, I use integers (4bytes in stead of 2).

Now, when I insert, no problem.
Strange, eh?

But wait, there's more.
When I create the same table again, but with bigints in stead of integers.
Again the 101 error.

The strange part is that integer lays between smallint and bigint when it
comes to memory used.

Trial-and-error revealed that with smallints, I could only insert 276 rows.

Is this solved by APAR? (currently using fp5).
Does anyone know what this is all about? Is this a bug, a feature,
something I missing here?

Help is greatly appreciated.
Greetings,

-R-

That is working as designed. Let me first assume that you stay below the
64K statement length limit appliable before V8.2.
By default any literal number is presumed by DB2 to be an INTEGER (I
think that's SQL Standard - important to know for function resolution!)
even if the value would fit into a SMALLINT. (By the same token strings
are VARCHAR, not CHAR - go figure....)
When you now INSERT such a constant into a column that is of a different
data type DB2 will have to inject an implicit cast for the assignment.
As the SQL compiler does that it figures that it can save some runtime
work by pre-computing the resulting expression. e.g.
CAST(5 /*integer*/ AS SMALLINT)
to 5 /*smallint*/
We call this "constant folding". The SQL Compiler remembers all
constants that it has come across in the hope to reuse them.
So it will now remmber the smallint 5 and the int 5. This is what drives
up the memory usage. At some point during compilation of teh SQL
statement DB2 frees the unreferenced values, but you never reach that spot.
So.. working as designed, in general not not harmful.
check out:
UPDATE DB CFG FOR <db> USING STMTHEAPSZ <biggervalue.. e.g. 1000>
This should work online if I recall correctly.. no need to restart or
disconnect.
In FP5 you should then be able to crank the statement up to 64k.

I do have a follow up comment though:
Are you composing these statements and fire them in a loop (like
inserting 10,000 rows 200 rows at a time? You would be a lot better
ofusing parameter parkers and host hostvariables and save the
compilation cost.
I have had very good experince with a set of insert statements with
differnt number of rows. E.g. 4096, 1024, 256, 64, 16, 4, 1.
This way you compile 7 statements total and your burn though the batch
quickly by taking the biggest available at any time.

Cheers
Serge
--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #2
Serge Rielau wrote:
I do have a follow up comment though:
Are you composing these statements and fire them in a loop (like
inserting 10,000 rows 200 rows at a time? You would be a lot better
ofusing parameter parkers and host hostvariables and save the
compilation cost.
I have had very good experince with a set of insert statements with
differnt number of rows. E.g. 4096, 1024, 256, 64, 16, 4, 1.
This way you compile 7 statements total and your burn though the batch
quickly by taking the biggest available at any time.


The Spatial Extender does something like that in a slightly different way.
The statement is constructed for as many rows as possibly (limited only be
the 64K statement size). Now that statement is compiled and used as often
as possible. For the last rows, for which the statement is too big, we
build a new statement for fewer rows. Only 2 compiles instead of 7. ;-))

--
Knut Stolze
Information Integration
IBM Germany / University of Jena
Nov 12 '05 #3
Knut Stolze wrote:
Serge Rielau wrote:

I do have a follow up comment though:
Are you composing these statements and fire them in a loop (like
inserting 10,000 rows 200 rows at a time? You would be a lot better
ofusing parameter parkers and host hostvariables and save the
compilation cost.
I have had very good experince with a set of insert statements with
differnt number of rows. E.g. 4096, 1024, 256, 64, 16, 4, 1.
This way you compile 7 statements total and your burn though the batch
quickly by taking the biggest available at any time.

The Spatial Extender does something like that in a slightly different way.
The statement is constructed for as many rows as possibly (limited only be
the 64K statement size). Now that statement is compiled and used as often
as possible. For the last rows, for which the statement is too big, we
build a new statement for fewer rows. Only 2 compiles instead of 7. ;-))

But the cleanup INSERT has a different # rows per batch. So that second
compile may not be reused. So it depends on the application

--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #4
Serge Rielau wrote:
Knut Stolze wrote:
Serge Rielau wrote:

I do have a follow up comment though:
Are you composing these statements and fire them in a loop (like
inserting 10,000 rows 200 rows at a time? You would be a lot better
ofusing parameter parkers and host hostvariables and save the
compilation cost.
I have had very good experince with a set of insert statements with
differnt number of rows. E.g. 4096, 1024, 256, 64, 16, 4, 1.
This way you compile 7 statements total and your burn though the batch
quickly by taking the biggest available at any time.

The Spatial Extender does something like that in a slightly different
way. The statement is constructed for as many rows as possibly (limited
only be
the 64K statement size). Now that statement is compiled and used as
often
as possible. For the last rows, for which the statement is too big, we
build a new statement for fewer rows. Only 2 compiles instead of 7. ;-))

But the cleanup INSERT has a different # rows per batch. So that second
compile may not be reused. So it depends on the application


Yes, that's right. In that particular scenario, we needed dynamic SQL in
any case because the table structure is only known at runtime. So reusing
compiled statements isn't really an issue in the first place.

--
Knut Stolze
Information Integration
IBM Germany / University of Jena
Nov 12 '05 #5
On Mon, 24 Jan 2005 09:19:52 +0100, Knut Stolze wrote:
Knut Stolze wrote:
Serge Rielau wrote:

---

Thank you for your comments.
It's clear to me what the situation is.
Instead of cranking up the statement heap, I will iterate through the
inserts per n and insert those using a prepared statement. (I will have to
test if it helps when I cast the values during insert time).

-R-
Nov 12 '05 #6
J.Haan wrote:
On Mon, 24 Jan 2005 09:19:52 +0100, Knut Stolze wrote:
Knut Stolze wrote:
Serge Rielau wrote:

---

Thank you for your comments.
It's clear to me what the situation is.
Instead of cranking up the statement heap, I will iterate through the
inserts per n and insert those using a prepared statement. (I will have to
test if it helps when I cast the values during insert time).


Depending on what you want to do, the casting might actually be necessary.
For example, if you build a statement like this:

INSERT INTO ...
SELECT ..., udf(...), ...
FROM ( SELECT ...
FROM TABLE ( VALUES (...), (...), (...) ) AS t(...) )

In such a case, you'd have to CAST the values so that DB2 knows the proper
data type needed for function resolution.

--
Knut Stolze
Information Integration
IBM Germany / University of Jena
Nov 12 '05 #7
J.Haan wrote:
On Mon, 24 Jan 2005 09:19:52 +0100, Knut Stolze wrote:

Knut Stolze wrote:

Serge Rielau wrote:


---

Thank you for your comments.
It's clear to me what the situation is.
Instead of cranking up the statement heap, I will iterate through the
inserts per n and insert those using a prepared statement. (I will have to
test if it helps when I cast the values during insert time).

-R-

Explicit vs. implicit casting makes no difference to that respect.
What's bad about cranking up the heap a bit? The default is very low.

Cheers
Serge
--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #8
On Mon, 24 Jan 2005 09:09:24 -0500, Serge Rielau wrote:
>Serge Rielau wrote:

Explicit vs. implicit casting makes no difference to that respect.
What's bad about cranking up the heap a bit? The default is very low.

Cheers
Serge


Agreed. cranking the heap up a bit is not a bad idea since the default is
indeed quite low. But the routine that's causing problems can grow fairly
large, so if I increase it now, it might be too small again in a couple of
months, and we cannot have that. :-) So we have to alter the routine a bit
so that it iterates using blocks. This way it doesn't matter how many
records are inserted.

-R-

Nov 12 '05 #9

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

4
by: Trevor Fairchild | last post by:
I've got a program that parses text files. The text files come to me in Unicode and they contain goofy characters that VB chokes on - treats them as eof markers. I have already been through this...
3
by: Pierre Espenan | last post by:
A have a long integer class. The built integer type within a conditional statement returns bool false for int i=0 and bool true for any other non zero value. I want my long integer class to have...
1
by: Maria | last post by:
Hello I have not used db2 in a long time, and I have this very long insert script, which is giving me an error of duplicated inserts. My question is how can I put something in the statment so...
8
by: 73blazer | last post by:
Hello, I'm looking for a way to make some of my insert templates more readable by placing comments in between the values. I cannot seem to find a way to do this with DB2, is there a way? I'm...
8
by: sapnsapn | last post by:
There is a statement in c code I am reviewing filenum = atoll(item->d_name + strlen(msgid_with_append_str) + 1); In a certain snapshot, item->d_name = 050707143827.AAAA.11810.00000001...
1
by: Me, Myself, and I | last post by:
First off, i apologize if my terminology is off... I am currently in a project that is basically a front-end to a database. In coding this, I am taking into account that it has the *potential*...
2
by: Denis Correard | last post by:
I have an application that create an insert statment on the fly (it would be to complex to create stored procedures for all senarios) like: insert into Table (field1, field2,field3 ,field4 ) VALUES...
4
by: Fredy Halter | last post by:
the following code is not working: std::complex<long doublex(1.,1.); std::complex<long doubleresult(0.,0.); result = 1./x; std::cout << "x = " << x << std::endl; std::cout << "r = " <<...
1
by: zeebiggie | last post by:
Good morning I have a form with the controls in the insert statment below. table1 has an Auto increment primary key hence is omitted in the insert statment and form. Am getting the error It didnt...
0
by: taylorcarr | last post by:
A Canon printer is a smart device known for being advanced, efficient, and reliable. It is designed for home, office, and hybrid workspace use and can also be used for a variety of purposes. However,...
0
by: Charles Arthur | last post by:
How do i turn on java script on a villaon, callus and itel keypad mobile phone
0
by: ryjfgjl | last post by:
In our work, we often receive Excel tables with data in the same format. If we want to analyze these data, it can be difficult to analyze them because the data is spread across multiple Excel files...
0
by: emmanuelkatto | last post by:
Hi All, I am Emmanuel katto from Uganda. I want to ask what challenges you've faced while migrating a website to cloud. Please let me know. Thanks! Emmanuel
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.