Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Ask for help in index Expand / Collapse
Author
Message
Posted Wednesday, December 26, 2012 4:12 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, August 25, 2014 6:53 AM
Points: 63, Visits: 563
Hi,

I'm a beginner in index.

I've table and data as following,
CREATE TABLE [dbo].[Zip](
[City_Cd] [varchar](100) NULL,
[Zip_Cd] [varchar](10) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
INSERT [dbo].[Zip] ([City_Cd], [Zip_Cd]) VALUES (N'Mobile', N'36601')
INSERT [dbo].[Zip] ([City_Cd], [Zip_Cd]) VALUES (N'New Orleans', N'70121')
INSERT [dbo].[Zip] ([City_Cd], [Zip_Cd]) VALUES (N'Luling', N'70070')
/****** Object: Table [dbo].[State] Script Date: 12/26/2012 19:01:30 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[State](
[State_Cd] [char](2) NULL,
[Descr] [varchar](150) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
INSERT [dbo].[State] ([State_Cd], [Descr]) VALUES (N'AL', N'Alabama')
INSERT [dbo].[State] ([State_Cd], [Descr]) VALUES (N'LA', N'Louisiana')
/****** Object: Table [dbo].[City] Script Date: 12/26/2012 19:01:30 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[City](
[State_Cd] [char](2) NULL,
[City_Cd] [varchar](100) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
INSERT [dbo].[City] ([State_Cd], [City_Cd]) VALUES (N'AL', N'Mobile')
INSERT [dbo].[City] ([State_Cd], [City_Cd]) VALUES (N'LA', N'New Orleans')
INSERT [dbo].[City] ([State_Cd], [City_Cd]) VALUES (N'LA', N'Luling')

Then, I execute SQL as following
SELECT s.[Descr],c.City_Cd
FROM dbo.[State] s
INNER JOIN dbo.[City] c ON s.[State_Cd] = c.[State_Cd]

The Execution Plan as following,


Then, I create an index as following
CREATE NONCLUSTERED INDEX [IX_State_State_Cd_001] ON [dbo].[State] 
(
[State_Cd] ASC
)
INCLUDE ( [Descr]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]


CREATE NONCLUSTERED INDEX [IX_City_State_Cd_001] ON [dbo].[City]
(
[State_Cd] ASC
)
INCLUDE ( [City_Cd]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]


Then, my Execution Plan as following



How do I want to make both of them (State and City) is Index Seek?

If it can, please guide me

Really looking for help
Post #1400206
Posted Wednesday, December 26, 2012 6:25 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 12:43 PM
Points: 2,109, Visits: 5,419
When SQL Server has to read very small tables, it many times uses table scan. In such small size, it doesn't make a difference.

Adi




--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Post #1400219
Posted Wednesday, December 26, 2012 6:44 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, August 25, 2014 6:53 AM
Points: 63, Visits: 563
Adi Cohn-120898 (12/26/2012)
When SQL Server has to read very small tables, it many times uses table scan. In such small size, it doesn't make a difference.

Adi




Sir,

If large table, the index scan will change into index seek?
Post #1400228
Posted Wednesday, December 26, 2012 9:00 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 12:43 PM
Points: 2,109, Visits: 5,419
There is a good chance that for large tables the server will do an index scan, but it depends on few more things. For example is the value that you are looking for is selective enough? The way that the code is written, If the statistics are updated etc'.

Adi



--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Post #1400271
Posted Wednesday, December 26, 2012 1:00 PM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 6:55 AM
Points: 42,817, Visits: 35,939
idyana (12/26/2012)
How do I want to make both of them (State and City) is Index Seek?


You can't.

A seek requires something to search for. Something to filter on. Your query requests the entire of two tables. The only sensible way for the entire of two tables to be queried is with a table scan.

This is true no matter how large the tables are (in fact in this case, larger tables would almost certainly result in two table scans because a table scan is the optimal way to read the entire of a table).
There is no possible way for your query to use two index seeks. One index seek comes from the join, but there's nothing seekable for the other. If you added a where clause to filter for specific cities or states you might see index seeks for both, because there would be something to search for.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1400346
Posted Thursday, January 10, 2013 3:53 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Monday, August 25, 2014 6:53 AM
Points: 63, Visits: 563
thanks to all
Post #1405324
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse