SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Indexes


Indexes

Author
Message
VM-723206
VM-723206
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1040 Visits: 267
Comments posted to this topic are about the item Indexes
The Dixie Flatline
The Dixie Flatline
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13096 Visits: 6903
Data type "bool"? What are you running?

Also, your statement is only true for the small number of rows in your example. Its a different story with real world volumes. Remember, SQL will choose what it feels is an optimal execution plan based on statistics.

Run the code below and compare the execution plan for your example against the execution plan for a table with even 100 rows. You'll see what I mean.


create table #t (id int,ch char,na varchar(20),flag char(1))

insert into #t values (2,'A','jack','Y')
insert into #t values (5,'b','amy','N')
insert into #t values (1,'$','adams','N')
insert into #t values (3,'*','anna','Y')
insert into #t values (7,'@','rose','N')
insert into #t values (4,'&','smith','Y')
insert into #t values (6,'!','sue','Y')

create nonclustered index nc_t on #t (id,ch,na)

-- query 1
select na from #t where ch = '!'
-- query 2
select na from #t where id = 6 and ch = '!'
-- query 3
select na from #t where ch = '!' and id = 6
-- query 4
select na from #t where flag = 'Y' and id = 6 and ch = '!'

;with tally (N) as (select row_number() over(order by id) from master..syscolumns)
select N as ID, ch, na, flag
into #bigT
from tally
cross join #t t
where N <=100

create nonclustered index nc_bigT on #bigT (id,ch,na)

-- query 1
select na from #bigT where ch = '!'
-- query 2
select na from #bigT where id = 6 and ch = '!'
-- query 3
select na from #bigT where ch = '!' and id = 6
-- query 4
select na from #bigT where flag = 'Y' and id = 6 and ch = '!'

drop table #t
drop table #bigT



__________________________________________________

Against stupidity the gods themselves contend in vain. -- Friedrich Schiller
Stop, children, what's that sound? Everybody look what's going down. -- Stephen Stills
Ahmad Osama
Ahmad Osama
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2767 Visits: 1660
table scan....I think it will be index scan....and query 1 will give a index scan...

Regards,
Sqlfrenzy
Ahmad Osama
Ahmad Osama
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2767 Visits: 1660
table scan....I think it will be index scan....and query 1 will give a index scan...

Regards,
Sqlfrenzy
ma-516002
ma-516002
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2589 Visits: 321
Can you explain what you mean with "Also, your statement is only true for the small number of rows..."?

I ran both your example and that from the question. On all queries the execution plan looks about the same, saying query 4 scans the table, while the others scan/seek the index with a dozen rows and 250+ rows in the table.

Since 3 columns (id,ch,na) are part of the index, no table scan should occure unless the forth column is addressed in the where clause.
dave.farmer
dave.farmer
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1337 Visits: 795
Hmmm... I played with this a little and the number of rows certainly makes a difference.

I added 10,000 rows (actually 10,001 - as below) and this time query 1 gave the only table scan and query 4 went for nested loops joining an Index Seek and a record id lookup, which is what I had expected it to do when I saw the question.

For the question as asked, I accept I got it wrong (I said Q1 as I thought all the others would perform an index seek but Q1 could not), but it is interesting how the question is not a simple one of the structure leading to a deterministic result, but the optimiser may take very different routes in the same database structures depending on other factors such as data volumes.

WITH cte (Num) AS
(
SELECT 0 Num

UNION ALL

SELECT Num + 1
FROM cte
WHERE Num < 10000
)
INSERT
INTO t (id, ch, na, flag)
SELECT num ,
CHAR(Num%128 + 50) ,
CAST(num AS VARCHAR),
CASE
WHEN Num%2 = 1
THEN 'Y'
ELSE 'N'
END
FROM cte OPTION(maxrecursion 10000)


Christian Buettner-167247
Christian Buettner-167247
SSCertifiable
SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)

Group: General Forum Members
Points: 5323 Visits: 3889
Please note that the data of this table fits in one data page - therefore a table scan is nothing more than reading one page of data. And doing row-id lookups is definitively more expensive than a single page read.

When you add more rows, the picture gets different.
If you expect only one row to be returned in a table with say 70000 rows, then the index seek + row id lookup (for one row) is much less expensive than a table scan (assume approx. 357 data pages) used for the 70000 rows.

Best Regards,

Chris Büttner
ma-516002
ma-516002
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2589 Visits: 321
Now that's interesting. I filled "t" with your script. Including my initial data, there are 10288 rows. I ran the four queries and still get the only table scan on #4. This is on SS2008 Developer Ed.
dave.farmer
dave.farmer
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1337 Visits: 795
ma (9/7/2009)
Now that's interesting. I filled "t" with your script. Including my initial data, there are 10288 rows. I ran the four queries and still get the only table scan on #4. This is on SS2008 Developer Ed.


Did you rebuild the index?

What I found was:

Initial conditions:
1) Index Scan
4) Table Scan

After adding 10001 rows:
1) Index Scan
4) Index Seek & RowID lookup

After rebuilding index
1) Table Scan
4) Index Seek & RowID lookup
ma-516002
ma-516002
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2589 Visits: 321
After rebuilding the index I also get a table scan on querie 1.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search