By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
438,779 Members | 1,101 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 438,779 IT Pros & Developers. It's quick & easy.

MERGE in V8.2 FP4 (on condition returns multiple rows from target)

P: n/a
Hi:

This is a merge questions which has been posted and answered... in my
case need more clairification when target table (tableB) matched
multiple rows to be updated based on the ON condition for a single row
from source table (tableA). There is a one to many relationship from
source to target table (because of the ON condition). We also know
upfront that thsi merge will result in all update and no inserts.

The source table is tableA and target is tableB. tableA has 2.5 million
rows and tableB after applying ON condition qualifies 8 million rows
for update only.

DB2 can update multiple rows on target tableB (tested it using the
sample database). But in this case, the merge is very slow and runs
forvever... I can only see it reading rows from application snapshot
which is in billions. There are indexes on both the tables to satifsy
the ON condition and the where conditions. db2advis has nothing to
advise here :)

Thanks for your help!

Vijay
The merge statement is:

merge into tableB as B
using (select cola, colb.... colz
from tableA
where col2 = 1266
and col3 ='C'
and batchno = '200602'
) as A
on B.col1 = A.col1
and B.col2 = A.col2
and B.col2 = 1266
and B.col3 IN ('C','A','D','P')
and B.col4 <= '200602'
when matched then UPDATE
set cola = ... colb = ... colz =
when NOT matched then INSERT
(list of columns) VALUES (list of column values)

Apr 6 '06 #1
Share this Question
Share on Google+
11 Replies


P: n/a
I would run runstats on the tables and indexes with distribution on key
columns. If that does not help, then alter the tables to volatile to
encourage index usage.

Also consider installing the latest fixpack (FP11). FP4 is quite old,
and had more bugs than an ant farm.

Apr 6 '06 #2

P: n/a
Thanks for the inputs. The database is on 8.2 FP4 = 8.1 FP11 :)
Have current statistics for both the tables... I will give volaitle a
try.
Thanks again.
Vijay

Apr 6 '06 #3

P: n/a
UDBDBA wrote:
We also know
upfront that thsi merge will result in all update and no inserts.

If you know there will be no INSERT, why do you specify the WHEN NOT
MATCHED branch then?

It would be interesting to see the db2exfmt output after removing INSERT.

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab
Apr 6 '06 #4

P: n/a
Thanks Serge for looking into this splurging merge!

I had the query initially without the insert section and that ran
forever... So i modified and tried after adding insert section, still
runs forever. All rows from source table needs to be processed/merged
with target table. I have enabled VOLATILE for both target & source
table.

The plan for the statement without insert section is given below.

Access Plan:
-----------
Total Cost: 2.79767e+06
Query Degree: 0

Rows
RETURN
( 1)
Cost
I/O
|
98031.8
UPDATE
( 2)
2.79767e+06
340016
/----+----\
98031.8 5.03874e+07
FETCH TABLE: STELLA
( 3) TARGET_TABLE
1.53744e+06
241984
/---+---\
98031.8 5.03874e+07
FILTER TABLE: STELLA
( 4) TARGET_TABLE
276995
143952
|
2.4508e+06
FILTER
( 5)
276002
143952
|
2.4508e+06
TBSCAN
( 6)
271953
143952
|
2.4508e+06
SORT
( 7)
269658
143952
|
2.4508e+06
HSJOIN
( 8)
263207
143952
/-----------+-----------\
418199 2.4508e+06
FETCH FETCH
( 9) ( 11)
40262.6 221849
5937.19 138015
/---+---\ /----+---\
418199 5.03874e+07 2.4508e+06 2.4508e+06
IXSCAN TABLE: STELLA IXSCAN TABLE: STAGE
( 10) TARGET_TABLE ( 12) SOURCE_TABLE
1261.09 19572.5
90.4042 1829
| |
5.03874e+07 2.4508e+06
INDEX: STELLA INDEX: DB2DW1
IX_TARGETTBL_MDC IDX_SOURCETBL

Apr 6 '06 #5

P: n/a
UDBDBA wrote:
/---+---\
98031.8 5.03874e+07
FILTER TABLE: STELLA
( 4) TARGET_TABLE
276995
143952
|
2.4508e+06
FILTER
( 5)
276002
143952
|
2.4508e+06
TBSCAN
( 6)
271953
143952
|
2.4508e+06
SORT
( 7)
269658
143952 This stack does the accounting to assure that each row in the target is
matched by at most one row in the source.
It gets added when Db2 fails to prove that the ON clause identifies
unique rows.
Now, semantically I don't see why it should care if a a single source
matches multiple targets.on B.col1 = A.col1
and B.col2 = A.col2

Is tableA(col1, col2) a unique key?

Cheers
Serge

PS; I hate hashjoins with MERGE. Drop the optimization level to 3
(disable hashjoin) and see what happens.

--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab
Apr 6 '06 #6

P: n/a
Yes. FOr the source tableA(col1,col2) is unique (infact col1 is unique
on tableA). But the same col1 on target tableB is not unique.

Counts for tableA: Source table
=========================
count(distinct col1) = 2450795
count(distinct col2) = 1
count(col1) = 2450795
count(col2) = 2450795

Counts for tableB: Target table
=========================
count(distinct col1) = 15197539
count(distinct col2) = 1
count(col1) = 50387384
count(col2) = 7950845

Thanks for your time & appreciate all the help.

Vijay

Apr 7 '06 #7

P: n/a
Correction on the counts:

For counts on tableB: Target table
===========================
count(distinct col1) = 2450795
count(distinct col2) = 1
count(col1) = 50387384
count(col2) = 2450795

Thanks.

Vijay

Apr 7 '06 #8

P: n/a
Hi Serge:
I turned volatile ON and gave selectivity of 0.00001 for col2, col3 and
col4 (on all = predicates). This time the merge finished in 84 minutes
at optimizer level 5. That's a major improvement compared to running
forever. And you were right about HSJOIN, The new plan has NLJOIN and
does improve merge performance.

By using selectivity, did i just get lucky?

Here is the new access plan:

Access Plan:
-----------
Total Cost: 48.673
Query Degree: 0

Rows
RETURN
( 1)
Cost
I/O
|
9.80318e-06
UPDATE
( 2)
48.673
4.3619
/----+----\
9.80318e-06 5.03874e+07
FILTER TABLE: STELLA
( 3) TARGET_TABLE
48.6726
4.36189
|
0.000245079
NLJOIN
( 4)
48.6726
4.36189
/-----------+-----------\
0.000245079 5.23167e-11
FETCH FETCH
( 5) ( 7)
35.8071 25.7169
3.36186 2.00003
/---+---\ /----+---\
24.5079 2.4508e+06 3.3155e-05 5.03874e+07
IXSCAN TABLE: STAGE IXSCAN TABLE: STELLA
( 6) SOURCE_TABLE ( 8) TARGET_TABLE
21.2964 25.7164
2 2
| |
2.4508e+06 5.03874e+07
INDEX: DB2DW1 INDEX: DB2DW1
IDX6040122122900 IDX6040122141000

thanks!

Vijay

Apr 7 '06 #9

P: n/a
UDBDBA wrote:
Hi Serge:
I turned volatile ON and gave selectivity of 0.00001 for col2, col3 and
col4 (on all = predicates). This time the merge finished in 84 minutes
at optimizer level 5. That's a major improvement compared to running
forever. And you were right about HSJOIN, The new plan has NLJOIN and
does improve merge performance.

By using selectivity, did i just get lucky?

Here is the new access plan:

Access Plan:
-----------
Total Cost: 48.673
Query Degree: 0

Rows
RETURN
( 1)
Cost
I/O
|
9.80318e-06
UPDATE
( 2)
48.673
4.3619
/----+----\
9.80318e-06 5.03874e+07
FILTER TABLE: STELLA
( 3) TARGET_TABLE
48.6726
4.36189
|
0.000245079
NLJOIN
( 4)
48.6726
4.36189
/-----------+-----------\
0.000245079 5.23167e-11
FETCH FETCH
( 5) ( 7)
35.8071 25.7169
3.36186 2.00003
/---+---\ /----+---\
24.5079 2.4508e+06 3.3155e-05 5.03874e+07
IXSCAN TABLE: STAGE IXSCAN TABLE: STELLA
( 6) SOURCE_TABLE ( 8) TARGET_TABLE
21.2964 25.7164
2 2
| |
2.4508e+06 5.03874e+07
INDEX: DB2DW1 INDEX: DB2DW1
IDX6040122122900 IDX6040122141000

Perfect plan!
I'm a bit confused because the mess above the join also went away, but I
take it. I imagine that the SELECTIVITY helped to change to NLJOIN.

This is how a well behaved MERGE should look like!
Now you can add your INSERT back it AFTER the UPDATE branch.
This should add a above TEMP (can't be helped) and the INSERT on top of
that.

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab
Apr 7 '06 #10

P: n/a
Thanks Serge and others for the inputs

Vijay

Apr 7 '06 #11

P: n/a
UDBDBA wrote:
Thanks Serge and others for the inputs

Vijay


Hi!

Can you please post the latest statement so I can compare it to the original
and see what exactly did you do?

Best regards,
Kovi
--
-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~
| Gregor Kovac | Gr**********@mikropis.si |
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
| In A World Without Fences Who Needs Gates? |
| Experience Linux. |
-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~-~
Apr 10 '06 #12

This discussion thread is closed

Replies have been disabled for this discussion.