February 11, 2013 at 11:47 pm
Hi,
I have 81 columns in my table. and record count=6690237. clustered index is been applied on PK.
when i execute below select statement it is taking 3 min to process.
select distinct divCode
,convert(varchar(4),glPeriodYear) + '/' + right('00' + convert(varchar(2),glPeriodMonth),2) + '/' + '01' as glPeriod
from tblGLJnlEntrySum
where divCode = @vsDivCode
order by divCode,glPeriod desc
Please tell me how i can speed up my query. need some suggestion on performance tuning.
February 12, 2013 at 12:49 am
Please post table definitions, index definitions and execution plan, as per http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Is the distinct really necessary?
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
February 12, 2013 at 3:02 am
Table Creation
/****** Object: Table [dbo].[tblGLJnlEntrySum] Script Date: 02/12/2013 04:55:15 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[tblGLJnlEntrySum](
[BatchID] [bigint] NOT NULL,
[RecID] [bigint] NOT NULL,
[GLBatchID] [bigint] NOT NULL,
[GLRecID] [bigint] IDENTITY(1,1) NOT NULL,
[DivCode] [varchar](3) NOT NULL,
[DivName] [varchar](50) NOT NULL,
[CurrencyID] [varchar](3) NOT NULL,
[GLAcctNbrP1] [varchar](30) NOT NULL,
[GLAcctNbrP2] [varchar](30) NULL,
[GLAcctNbrP3] [varchar](30) NULL,
[GLAcctNbrP4] [varchar](30) NULL,
[GLAcctNbrP5] [varchar](30) NULL,
[GrpGLAcctNbr] [varchar](255) NOT NULL,
[GrpGLAcctType] [varchar](2) NULL,
[AcctPeriod] [varchar](2) NOT NULL,
[AcctYear] [varchar](4) NOT NULL,
[AcctBalance] [money] NULL,
[ProcessedDate] [datetime] NULL,
[ProcessedFlag] [bit] NOT NULL,
[GPProcessID] [bigint] NULL,
[GPBatchID] [char](15) NULL,
[GPErrorFlag] [int] NULL,
[GPDatabase] [varchar](60) NULL,
[CreatedDate] [datetime] NOT NULL,
[CreatedUser] [varchar](255) NOT NULL,
[UpdatedDate] [datetime] NULL,
[UpdatedUser] [varchar](255) NULL,
[GLAcctDescP1] [varchar](60) NULL,
[GLAcctDescP2] [varchar](60) NULL,
[GLAcctDescP3] [varchar](60) NULL,
[GLAcctDescP4] [varchar](60) NULL,
[GLAcctDescP5] [varchar](60) NULL,
[GLAcctDesc] [varchar](255) NULL,
[glPeriodYear] [int] NULL,
[glPeriodMonth] [int] NULL,
[glEntityCode] [varchar](50) NULL,
[glEntityDesc] [varchar](100) NULL,
[glAcctCode] [varchar](50) NULL,
[glSubEntityCode] [varchar](50) NULL,
[glSubEntityDesc] [varchar](100) NULL,
[glAcctTypeCode] [varchar](50) NULL,
[glAcctTypeDesc] [varchar](100) NULL,
[flexCode01] [varchar](50) NULL,
[flexDesc01] [varchar](100) NULL,
[flexCode02] [varchar](50) NULL,
[flexDesc02] [varchar](100) NULL,
[flexCode03] [varchar](50) NULL,
[flexDesc03] [varchar](100) NULL,
[flexCode04] [varchar](50) NULL,
[flexDesc04] [varchar](100) NULL,
[flexCode05] [varchar](50) NULL,
[flexDesc05] [varchar](100) NULL,
[flexCode06] [varchar](50) NULL,
[flexDesc06] [varchar](100) NULL,
[flexCode07] [varchar](50) NULL,
[flexDesc07] [varchar](100) NULL,
[flexCode08] [varchar](50) NULL,
[flexDesc08] [varchar](100) NULL,
[flexCode09] [varchar](50) NULL,
[flexDesc09] [varchar](100) NULL,
[flexCode10] [varchar](50) NULL,
[flexDesc10] [varchar](100) NULL,
[glAcctYTDBalance] [money] NULL,
[glAcctMonthDebitAmt] [money] NULL,
[glAcctMonthCreditsAmt] [money] NULL,
[glAcctMonthNetChangeAmt] [money] NULL,
[CurrencyCode] [varchar](3) NULL,
[FileCreateDate] [datetime] NULL,
[grpEntityID] [varchar](2) NULL,
[grpEntityErrorFlag] [varchar](1) NULL,
[grpSubEntityID] [varchar](3) NULL,
[grpSubEntityErrorFlag] [varchar](1) NULL,
[grpGLAcctCode] [varchar](4) NULL,
[grpGLAcctCodeErrorFlag] [varchar](1) NULL,
[grpGLAcctNumberErrorFlag] [varchar](1) NULL,
[recordErrorFlag] [varchar](1) NULL,
[recordSource] [varchar](50) NULL,
[createdBy] [varchar](50) NULL,
[createTimeStamp] [datetime] NULL,
[updatedBy] [varchar](50) NULL,
[updateTimeStamp] [datetime] NULL,
CONSTRAINT [tblGLJnlEntrySum_PK] PRIMARY KEY CLUSTERED
(
[GLRecID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] WITH NOCHECK ADD CONSTRAINT [FK_tblGLJnlEntrySum_tblDivision_DIM] FOREIGN KEY([DivCode])
REFERENCES [dbo].[tblDivision_DIM] ([DivCode])
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] CHECK CONSTRAINT [FK_tblGLJnlEntrySum_tblDivision_DIM]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF_tblGLJnlEntrySum_CurrencyID] DEFAULT ('USD') FOR [CurrencyID]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF__tblGLJnlE__Proce__703EA55A] DEFAULT ((0)) FOR [ProcessedFlag]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF__tblGLJnlE__Creat__7132C993] DEFAULT (getdate()) FOR [CreatedDate]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF__tblGLJnlE__Creat__7226EDCC] DEFAULT (suser_sname()) FOR [CreatedUser]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF_tblGLJnlEntrySum_createdBy] DEFAULT (suser_sname()) FOR [createdBy]
GO
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [DF_tblGLJnlEntrySum_createTimeStamp] DEFAULT (getdate()) FOR [createTimeStamp]
GO
Trigger used on top of table
/****** Object: Trigger [dbo].[tblGLJnlEntrySum_TRU01] Script Date: 02/12/2013 04:56:18 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TRIGGER [dbo].[tblGLJnlEntrySum_TRU01]
ON [dbo].[tblGLJnlEntrySum]
FOR UPDATE
AS
BEGIN
update tblGLJnlEntrySum
set UpdatedDate = getdate(),
UpdatedUser = IsNull(deleted.UpdatedUser,suser_sname())
from deleted
where tblGLJnlEntrySum.GLRecID = deleted.GLRecID
END
GO
Indexes
/****** Object: Index [IX_tblGLJnlEntrySum] Script Date: 02/12/2013 04:57:26 ******/
CREATE NONCLUSTERED INDEX [IX_tblGLJnlEntrySum] ON [dbo].[tblGLJnlEntrySum]
(
[DivCode] ASC
)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, FILLFACTOR = 80) ON [PRIMARY]
GO
USE [dbSDUSAReporting]
GO
/****** Object: Index [tblGLJnlEntrySum_IX01] Script Date: 02/12/2013 04:58:33 ******/
CREATE NONCLUSTERED INDEX [tblGLJnlEntrySum_IX01] ON [dbo].[tblGLJnlEntrySum]
(
[DivCode] ASC,
[GLAcctNbrP1] ASC,
[AcctPeriod] ASC,
[AcctYear] ASC,
[AcctBalance] ASC
)
INCLUDE ( [GLAcctNbrP2],
[GLAcctNbrP3],
[GLAcctNbrP4],
[GLAcctNbrP5]) 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, FILLFACTOR = 80) ON [PRIMARY]
GO
USE [dbSDUSAReporting]
GO
/****** Object: Index [tblGLJnlEntrySum_IX02] Script Date: 02/12/2013 04:58:56 ******/
CREATE NONCLUSTERED INDEX [tblGLJnlEntrySum_IX02] ON [dbo].[tblGLJnlEntrySum]
(
[DivCode] ASC,
[AcctYear] ASC,
[AcctPeriod] ASC,
[GrpGLAcctNbr] ASC,
[GLAcctNbrP1] ASC,
[GLRecID] ASC,
[CurrencyID] ASC,
[AcctBalance] ASC
)
INCLUDE ( [GLAcctNbrP2],
[GLAcctNbrP3],
[GLAcctNbrP4],
[GLAcctNbrP5],
[GrpGLAcctType],
[GLAcctDescP1],
[GLAcctDescP2],
[GLAcctDescP3],
[GLAcctDescP4],
[GLAcctDescP5]) 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, FILLFACTOR = 80) ON [PRIMARY]
GO
USE [dbSDUSAReporting]
GO
/****** Object: Index [tblGLJnlEntrySum_PK] Script Date: 02/12/2013 04:59:14 ******/
ALTER TABLE [dbo].[tblGLJnlEntrySum] ADD CONSTRAINT [tblGLJnlEntrySum_PK] PRIMARY KEY CLUSTERED
(
[GLRecID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
GO
February 12, 2013 at 3:13 am
Execution plan please.
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
February 12, 2013 at 3:42 am
Also what other indexes do you have on the tables asside from the Primary Keys?
February 12, 2013 at 4:55 am
Execution plan
Cost
select 0%
Parallelism(Gather Streams) 0%
Sort(Distinct Sort) 0%
Parallelism(Repartition Streams) 0%
Hash Match(Partial Aggregate) 3%
Compute Scalar 0%
Clustered Index Scan[tblGLJnlEntrySum].tblGLJnlEntrySum_PK 97%
Inaddition i am getting message like below
/*
Missing Index Details
The Query Processor estimates that implementing the following index could improve the query cost by 97.4146%.
*/
/*
CREATE NONCLUSTERED INDEX [<Name of Missing Index, sysname,>]
ON [dbo].[tblGLJnlEntrySum] ([DivCode])
INCLUDE ([glPeriodYear],[glPeriodMonth])
*/
so is that means that i have to create suc index mentioned above?
February 12, 2013 at 5:06 am
p.panneerselvam (2/12/2013)
Execution planCost
select 0%
Parallelism(Gather Streams) 0%
Sort(Distinct Sort) 0%
Parallelism(Repartition Streams) 0%
Hash Match(Partial Aggregate) 3%
Compute Scalar 0%
Clustered Index Scan[tblGLJnlEntrySum].tblGLJnlEntrySum_PK 97%
Inaddition i am getting message like below
/*
Missing Index Details
The Query Processor estimates that implementing the following index could improve the query cost by 97.4146%.
*/
/*
CREATE NONCLUSTERED INDEX [<Name of Missing Index, sysname,>]
ON [dbo].[tblGLJnlEntrySum] ([DivCode])
INCLUDE ([glPeriodYear],[glPeriodMonth])
*/
so is that means that i have to create suc index mentioned above?
The suggested index should improve your query yes. At the moment, SQL Server is having to scan the entire table looking for records where divCode = @vsDivCode. With the new index and included columns the scan should become an index seek on the new indexed column.
---------------------------------------------------------
It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
David Edwards - Media lens[/url]
Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
Howard Zinn
February 12, 2013 at 5:19 am
Hi,
my issue got fixed with the help of excution plan. i was missing required non-clustered index on top of my table.
Thanks
February 12, 2013 at 6:54 am
I take it you didn't read the article I referenced, as it shows how to save and attach the graphical plan.
Also, please post SQL 2008 questions in the SQL 2008 forums.
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
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply