December 26, 2012 at 4:12 am
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
December 26, 2012 at 6:25 am
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/
December 26, 2012 at 6:44 am
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?
December 26, 2012 at 9:00 am
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/
December 26, 2012 at 1:00 pm
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, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 10, 2013 at 3:53 am
thanks to all
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply