I'm curious about the computational complexity of a query I have. The
query contains multiple nested self left joins, starting with a simple
select, then doing a self left join with the results, then doing a self
left join with those results, etc. What puzzles me is that the time
required for the query seems to grow exponentially as I add additional
left joins, which I didn't expect. I expected the inner select to
return about 25 rows (it does), then I expected the self join to result
in about 25 rows (it does), etc. Each join just adds another column; it
doesn't add more rows. So the left part of the join is staying the same
size, and so is the right part of the join, since I'm always joining
with the same table.
So I would think the time for this query should be (time to join 25
rows against the source table) * (num joins), but it seems to be
something like (num rows) ^ (num joins). Any ideas? I'm just trying to
understand the system a little better. (But if you have any ideas about
improving the query, I'm always open to those, too.)
The execution plan is what you'd expect: an index seek loop-joined with
another index seek, the results of which are merge-joined with another
index seek, the results of which are merge-joined with another index
seek, ad nauseum, until a final "compute scalar cost (39%)" and "select
(0%)"
For the brave and curious, I've pasted the query below.
Thanks
select right(x.cp_yyyymm, 2)+'-'+left(x.cp_yyyymm, 4) as [Month],
table0.cp_num_loans/1 as [AFCM9704], table1.cp_num_loans/1 as
[AFC9104], table2.cp_num_loans/1 as [BFAT01C], table3.cp_num_loans/1 as
[BFAT02B], table4.cp_num_loans/1 as [BFAT03D], table5.cp_num_loans/1 as
[BFAT03E], table6.cp_num_loans/1 as [BFAT03F], table7.cp_num_loans/1 as
[BFAT04A], table8.cp_num_loans/1 as [BFAT04C], table9.cp_num_loans/1 as
[BFAT04D], table10.cp_num_loans/1 as [BFAT99C] from (((((((((((select
distinct cp_yyyymm from cp_deal_history where cp_deal_id in
('AFCM9704', 'AFC9104', 'BFAT01C', 'BFAT02B', 'BFAT03D', 'BFAT03E',
'BFAT03F', 'BFAT04A', 'BFAT04C', 'BFAT04D', 'BFAT99C') and cp_yyyymm
between 200304 and 200504) as x left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='AFCM9704') as
table0 on x.cp_yyyymm=table0.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='AFC9104') as table1
on x.cp_yyyymm=table1.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT01C') as table2
on x.cp_yyyymm=table2.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT02B') as table3
on x.cp_yyyymm=table3.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT03D') as table4
on x.cp_yyyymm=table4.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT03E') as table5
on x.cp_yyyymm=table5.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT03F') as table6
on x.cp_yyyymm=table6.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT04A') as table7
on x.cp_yyyymm=table7.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT04C') as table8
on x.cp_yyyymm=table8.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT04D') as table9
on x.cp_yyyymm=table9.cp_yyyymm) left join (select cp_yyyymm,
cp_num_loans from cp_deal_history where cp_deal_id='BFAT99C') as
table10 on x.cp_yyyymm=table10.cp_yyyymm order by x.cp_yyyymmFor those of you who's cranial parser requires liberal use of indents
and line breaks, I spent about an hour cleaning this up.
BTW, did you write this query to experiment with running times or are
you actually trying to accomplish something useful?
select right(x.cp_yyyymm, 2)+'-'+left(x.cp_yyyymm, 4) as [Month],
table0.cp_num_loans/1 as [AFCM9704],
table1.cp_num_loans/1 as [AFC9104],
table2.cp_num_loans/1 as [BFAT01C],
table3.cp_num_loans/1 as [BFAT02B],
table4.cp_num_loans/1 as [BFAT03D],
table5.cp_num_loans/1 as [BFAT03E],
table6.cp_num_loans/1 as [BFAT03F],
table7.cp_num_loans/1 as [BFAT04A],
table8.cp_num_loans/1 as [BFAT04C],
table9.cp_num_loans/1 as [BFAT04D],
table10.cp_num_loans/1 as [BFAT99C]
from (select distinct cp_yyyymm
from cp_deal_history
where cp_deal_id in
('AFCM9704', 'AFC9104', 'BFAT01C',
'BFAT02B', 'BFAT03D', 'BFAT03E',
'BFAT03F', 'BFAT04A', 'BFAT04C',
'BFAT04D', 'BFAT99C')
and cp_yyyymm between 200304 and 200504) as x
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='AFCM9704') as table0
on x.cp_yyyymm=table0.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='AFC9104') as table1
on x.cp_yyyymm=table1.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT01C') as table2
on x.cp_yyyymm=table2.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT02B') as table3
on x.cp_yyyymm=table3.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT03D') as table4
on x.cp_yyyymm=table4.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT03E') as table5
on x.cp_yyyymm=table5.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT03F') as table6
on x.cp_yyyymm=table6.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT04A') as table7
on x.cp_yyyymm=table7.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT04C') as table8
on x.cp_yyyymm=table8.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT04D') as table9
on x.cp_yyyymm=table9.cp_yyyymm)
left join (select cp_yyyymm, cp_num_loans
from cp_deal_history
where cp_deal_id='BFAT99C') as table10
on x.cp_yyyymm=table10.cp_yyyymm
order by x.cp_yyyymm|||Still not entirely sure what you're trying to accomplish, but -- if
you're doing what I think you are -- why not try something like this:
select right(x.cp_yyyymm, 2)+'-'+left(x.cp_yyyymm, 4) as [Month],
case when y.cp_deal_id = 'AFCM9704'
then y.cp_num_loans/1 else null end as [AFCM9704],
case when y.cp_deal_id = 'AFC9104'
then y.cp_num_loans/1 else null end as [AFC9104],
case when y.cp_deal_id = 'BFAT01C'
then y.cp_num_loans/1 else null end as [BFAT01C],
case when y.cp_deal_id = 'BFAT02B'
then y.cp_num_loans/1 else null end as [BFAT02B],
case when y.cp_deal_id = 'BFAT03D'
then y.cp_num_loans/1 else null end as [BFAT03D],
case when y.cp_deal_id = 'BFAT03E'
then y.cp_num_loans/1 else null end as [BFAT03E],
case when y.cp_deal_id = 'BFAT03F'
then y.cp_num_loans/1 else null end as [BFAT03F],
case when y.cp_deal_id = 'BFAT04A'
then y.cp_num_loans/1 else null end as [BFAT04A],
case when y.cp_deal_id = 'BFAT04C'
then y.cp_num_loans/1 else null end as [BFAT04C],
case when y.cp_deal_id = 'BFAT04D'
then y.cp_num_loans/1 else null end as [BFAT04D],
case when y.cp_deal_id = 'BFAT99C'
then y.cp_num_loans/1 else null end as [BFAT99C],
from (select distinct cp_yyyymm
from cp_deal_history
where cp_deal_id in
('AFCM9704', 'AFC9104', 'BFAT01C',
'BFAT02B', 'BFAT03D', 'BFAT03E',
'BFAT03F', 'BFAT04A', 'BFAT04C',
'BFAT04D', 'BFAT99C')
and cp_yyyymm between 200304 and 200504) as x
left outer join cp_deal_history y
on x.cp_yyyymm = y.cp_yyyymm
order by x.cp_yyyymm|||That is not great surprise. LEFT OUTER JOINs are not well optimized
and thigns get flaky about five self joins in most queries. The real
proglem is that your code is awful.
Why would anyone, except an 1950's COBOL programmer, store temporal
data in strings! Why did you name a column for its format and not its
contents? Time is always stored as durations in a temporal data type.
Why would you divide by integer 1 when the column looks like a count of
loans? Tell me that you did not store that data as strings too and
have to force type conversions!! Try this:
SELECT deal_date,
MAX(CASE WHEN deal_id = 'AFCM9704'
THEN loan_cnt ELSE NULL END) AS AFCM9704,
..
MAX(CASE WHEN deal_id = 'BFAT99C'
THEN loans_cnt ELSE NULL END) AS BFAT99C
FROM DealHistory
WHERE deal_date BETWEEN '2003-04-01' AND '2005-04-30'
GROUP BY deal_date;|||Sweet Jesus, ZeldorBlat, if I'd thought anyone was actually going to
look at that I'd have pretty-printed it myself. So I apologize, and
thank you for your effort. The query constructs the data for a chart,
with cp_yyyymm being the independent variable, and each row needing the
value of cp_num_loans for each month and each particular deal id. So
the result set needs exactly one row per month. Your suggested query is
definitely moving in the right direction, but it just pulls all the
data - it doesn't "filter" it and arrange it as required. After playing
around a little bit, the query I eventually got working was basically
what CELKO suggested:
select right(z.cp_yyyymm, 2)+'-'+left(z.cp_yyyymm, 4) as [Month],
max(AFCM9704_unfiltered) as [AFCM9704],
max(AFC9104_unfiltered) as [AFC9104],
max(BFAT01C_unfiltered) as [BFAT01C],
max(BFAT02B_unfiltered) as [BFAT02B],
max(BFAT03D_unfiltered) as [BFAT03D],
max(BFAT03E_unfiltered) as [BFAT03E],
max(BFAT03F_unfiltered) as [BFAT03F],
max(BFAT04A_unfiltered) as [BFAT04A],
max(BFAT04C_unfiltered) as [BFAT04C],
max(BFAT04D_unfiltered) as [BFAT04D],
max(BFAT99C_unfiltered) as [BFAT99C]
from
(select cp_yyyymm, cp_deal_id,
case when y.cp_deal_id = 'AFCM9704'
then y.cp_num_loans/1 else null end as [AFCM9704_unfiltered],
case when y.cp_deal_id = 'AFC9104'
then y.cp_num_loans/1 else null end as [AFC9104_unfiltered],
case when y.cp_deal_id = 'BFAT01C'
then y.cp_num_loans/1 else null end as [BFAT01C_unfiltered],
case when y.cp_deal_id = 'BFAT02B'
then y.cp_num_loans/1 else null end as [BFAT02B_unfiltered],
case when y.cp_deal_id = 'BFAT03D'
then y.cp_num_loans/1 else null end as [BFAT03D_unfiltered],
case when y.cp_deal_id = 'BFAT03E'
then y.cp_num_loans/1 else null end as [BFAT03E_unfiltered],
case when y.cp_deal_id = 'BFAT03F'
then y.cp_num_loans/1 else null end as [BFAT03F_unfiltered],
case when y.cp_deal_id = 'BFAT04A'
then y.cp_num_loans/1 else null end as [BFAT04A_unfiltered],
case when y.cp_deal_id = 'BFAT04C'
then y.cp_num_loans/1 else null end as [BFAT04C_unfiltered],
case when y.cp_deal_id = 'BFAT04D'
then y.cp_num_loans/1 else null end as [BFAT04D_unfiltered],
case when y.cp_deal_id = 'BFAT99C'
then y.cp_num_loans/1 else null end as [BFAT99C_unfiltered]
from cp_deal_history as y
where cp_deal_id in ('AFCM9704', 'AFC9104', 'BFAT01C', 'BFAT02B',
'BFAT03D', 'BFAT03E',
'BFAT03F', 'BFAT04A', 'BFAT04C', 'BFAT04D', 'BFAT99C')
and cp_yyyymm between 200304 and 200504) as z
group by z.cp_yyyymm
order by z.cp_yyyymm
Note the lack of a single join. Sigh - I don't know what I was
thinking. Thanks very much to both of you for your help. (I'm still
curious as to why the joins weren't working the way I expected, though.)
No comments:
Post a Comment