Confused execution plan

  • Extremely confused I am doing a

    select ID,primary key from tableA where ID =’123’

    This was never a problem on compatibility mode 80 sql 2005 SP2 win2003

    But now on

    compatibility mode 80 sql 2005 SP4 win2008 it takes ages

    What confuses me is

    1)that it uses the non-clustered index with ID to do an index seek.(as expected)

    2) But then it does an Index scan on the PK index?

    Why would it do this when it has already used the ID index?

    Many thanks

  • Please post the plan (actual plan, not estimated).

    Are the index defragmented and the stats up to date?

  • Plus table and index definitions.

    How many rows does that return?

    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

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Just tested it in a SP2 enviroment and its much quicker

  • Edward-445599 (5/9/2011)


    Just tested it in a SP2 enviroment and its much quicker

    Awesome, post that execution plan too plz.

  • Sorry about the delay here are the two plans first one good second one bad, the strange thing is that a few times when running this query in the SP4 environment (slow) it actually picked the right plan!! but 9 times out of 10 it didn't. I updated the stats on the table to no difference

    --GOOD PLAN ON SP3

    <?xml version="1.0" encoding="utf-16"?>

    <ShowPlanXML xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns:xsd="http://www.w3.org/2001/XMLSchema" Version="1.0" Build="9.00.4035.00" xmlns="http://schemas.microsoft.com/sqlserver/2004/07/showplan">

    <BatchSequence>

    <Batch>

    <Statements>

    <StmtSimple StatementCompId="1" StatementEstRows="62.4153" StatementId="1" StatementOptmLevel="FULL" StatementOptmEarlyAbortReason="GoodEnoughPlanFound" StatementSubTreeCost="0.205393" StatementText="SELECT [primaryKey],[id] FROM [prod-live].[schemA].[TableA] WHERE [id]=@1" StatementType="SELECT">

    <StatementSetOptions ANSI_NULLS="false" ANSI_PADDING="false" ANSI_WARNINGS="false" ARITHABORT="true" CONCAT_NULL_YIELDS_NULL="false" NUMERIC_ROUNDABORT="false" QUOTED_IDENTIFIER="false" />

    <QueryPlan DegreeOfParallelism="0" CachedPlanSize="27" CompileTime="7" CompileCPU="7" CompileMemory="232">

    <RelOp AvgRowSize="22" EstimateCPU="0.000260896" EstimateIO="0" EstimateRebinds="0" EstimateRewinds="0" EstimateRows="62.4153" LogicalOp="Inner Join" NodeId="0" Parallel="false" PhysicalOp="Nested Loops" EstimatedTotalSubtreeCost="0.205393">

    <OutputList>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    </OutputList>

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="0" ActualEndOfScans="1" ActualExecutions="1" />

    </RunTimeInformation>

    <NestedLoops Optimized="false" WithUnorderedPrefetch="true">

    <OuterReferences>

    <ColumnReference Column="Uniq1002" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Expr1004" />

    </OuterReferences>

    <RelOp AvgRowSize="27" EstimateCPU="0.000225657" EstimateIO="0.003125" EstimateRebinds="0" EstimateRewinds="0" EstimateRows="62.4153" LogicalOp="Index Seek" NodeId="2" Parallel="false" PhysicalOp="Index Seek" EstimatedTotalSubtreeCost="0.00335066">

    <OutputList>

    <ColumnReference Column="Uniq1002" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </OutputList>

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="0" ActualEndOfScans="1" ActualExecutions="1" />

    </RunTimeInformation>

    <IndexScan Ordered="true" ScanDirection="FORWARD" ForcedIndex="false" NoExpandHint="false">

    <DefinedValues>

    <DefinedValue>

    <ColumnReference Column="Uniq1002" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </DefinedValue>

    </DefinedValues>

    <Object Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Index="[IX_TableA_id]" />

    <SeekPredicates>

    <SeekPredicate>

    <Prefix ScanType="EQ">

    <RangeColumns>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    </RangeColumns>

    <RangeExpressions>

    <ScalarOperator ScalarString="'31519652'">

    <Const ConstValue="'31519652'" />

    </ScalarOperator>

    </RangeExpressions>

    </Prefix>

    </SeekPredicate>

    </SeekPredicates>

    </IndexScan>

    </RelOp>

    <RelOp AvgRowSize="11" EstimateCPU="0.0001581" EstimateIO="0.003125" EstimateRebinds="61.4153" EstimateRewinds="0" EstimateRows="1" LogicalOp="Clustered Index Seek" NodeId="4" Parallel="false" PhysicalOp="Clustered Index Seek" EstimatedTotalSubtreeCost="0.201782">

    <OutputList>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    </OutputList>

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="0" ActualEndOfScans="0" ActualExecutions="0" />

    </RunTimeInformation>

    <IndexScan Lookup="true" Ordered="true" ScanDirection="FORWARD" ForcedIndex="false" NoExpandHint="false">

    <DefinedValues>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    </DefinedValue>

    </DefinedValues>

    <Object Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Index="[CIX_TableA_offer]" TableReferenceId="-1" />

    <SeekPredicates>

    <SeekPredicate>

    <Prefix ScanType="EQ">

    <RangeColumns>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Uniq1002" />

    </RangeColumns>

    <RangeExpressions>

    <ScalarOperator ScalarString="[prod-live].[schemA].[TableA].[offer]">

    <Identifier>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </Identifier>

    </ScalarOperator>

    <ScalarOperator ScalarString="[Uniq1002]">

    <Identifier>

    <ColumnReference Column="Uniq1002" />

    </Identifier>

    </ScalarOperator>

    </RangeExpressions>

    </Prefix>

    </SeekPredicate>

    </SeekPredicates>

    </IndexScan>

    </RelOp>

    </NestedLoops>

    </RelOp>

    <ParameterList>

    <ColumnReference Column="@1" ParameterCompiledValue="'31519652'" ParameterRuntimeValue="'31519652'" />

    </ParameterList>

    </QueryPlan>

    </StmtSimple>

    </Statements>

    </Batch>

    </BatchSequence>

    </ShowPlanXML>

    --BAD PLAN SP4

    <?xml version="1.0" encoding="utf-16"?>

    <ShowPlanXML xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns:xsd="http://www.w3.org/2001/XMLSchema" Version="1.0" Build="9.00.5000.00" xmlns="http://schemas.microsoft.com/sqlserver/2004/07/showplan">

    <BatchSequence>

    <Batch>

    <Statements>

    <StmtSimple StatementCompId="1" StatementEstRows="420453" StatementId="1" StatementOptmLevel="FULL" StatementSubTreeCost="342.46" StatementText="SELECT [primaryKey],[id] FROM [prod-live].[schemA].[TableA] WHERE [id]=@1" StatementType="SELECT">

    <StatementSetOptions ANSI_NULLS="false" ANSI_PADDING="false" ANSI_WARNINGS="false" ARITHABORT="true" CONCAT_NULL_YIELDS_NULL="false" NUMERIC_ROUNDABORT="false" QUOTED_IDENTIFIER="false" />

    <QueryPlan DegreeOfParallelism="0" MemoryGrant="35459" CachedPlanSize="49" CompileTime="1" CompileCPU="1" CompileMemory="264">

    <MissingIndexes>

    <MissingIndexGroup Impact="99.9989">

    <MissingIndex Database="[prod-live]" Schema="[schemA]" Table="[TableA]">

    <ColumnGroup Usage="EQUALITY">

    <Column Name="[id]" ColumnId="2" />

    </ColumnGroup>

    </MissingIndex>

    </MissingIndexGroup>

    </MissingIndexes>

    <RelOp AvgRowSize="22" EstimateCPU="217.683" EstimateIO="0" EstimateRebinds="0" EstimateRewinds="0" EstimateRows="420453" LogicalOp="Inner Join" NodeId="1" Parallel="false" PhysicalOp="Hash Match" EstimatedTotalSubtreeCost="342.46">

    <OutputList>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    </OutputList>

    <MemoryFractions Input="1" Output="1" />

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="1" ActualEndOfScans="1" ActualExecutions="1" />

    </RunTimeInformation>

    <Hash>

    <DefinedValues />

    <HashKeysBuild>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Uniq1002" />

    </HashKeysBuild>

    <HashKeysProbe>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Uniq1002" />

    </HashKeysProbe>

    <ProbeResidual>

    <ScalarOperator ScalarString="[prod-live].[schemA].[TableA].[offer] = [prod-live].[schemA].[TableA].[offer] AND [Uniq1002] = [Uniq1002]">

    <Logical Operation="AND">

    <ScalarOperator>

    <Compare CompareOp="IS">

    <ScalarOperator>

    <Identifier>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </Identifier>

    </ScalarOperator>

    <ScalarOperator>

    <Identifier>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </Identifier>

    </ScalarOperator>

    </Compare>

    </ScalarOperator>

    <ScalarOperator>

    <Compare CompareOp="IS">

    <ScalarOperator>

    <Identifier>

    <ColumnReference Column="Uniq1002" />

    </Identifier>

    </ScalarOperator>

    <ScalarOperator>

    <Identifier>

    <ColumnReference Column="Uniq1002" />

    </Identifier>

    </ScalarOperator>

    </Compare>

    </ScalarOperator>

    </Logical>

    </ScalarOperator>

    </ProbeResidual>

    <RelOp AvgRowSize="31" EstimateCPU="0.462655" EstimateIO="1.68647" EstimateRebinds="0" EstimateRewinds="0" EstimateRows="420453" LogicalOp="Index Seek" NodeId="2" Parallel="false" PhysicalOp="Index Seek" EstimatedTotalSubtreeCost="2.14913">

    <OutputList>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Uniq1002" />

    </OutputList>

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="1" ActualEndOfScans="1" ActualExecutions="1" />

    </RunTimeInformation>

    <IndexScan Ordered="true" ScanDirection="FORWARD" ForcedIndex="false" NoExpandHint="false">

    <DefinedValues>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Column="Uniq1002" />

    </DefinedValue>

    </DefinedValues>

    <Object Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Index="[IX_TableA_id]" />

    <SeekPredicates>

    <SeekPredicate>

    <Prefix ScanType="EQ">

    <RangeColumns>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="id" />

    </RangeColumns>

    <RangeExpressions>

    <ScalarOperator ScalarString="'31519652'">

    <Const ConstValue="'31519652'" />

    </ScalarOperator>

    </RangeExpressions>

    </Prefix>

    </SeekPredicate>

    </SeekPredicates>

    </IndexScan>

    </RelOp>

    <RelOp AvgRowSize="26" EstimateCPU="34.6485" EstimateIO="87.9794" EstimateRebinds="0" EstimateRewinds="0" EstimateRows="31498500" LogicalOp="Index Scan" NodeId="3" Parallel="false" PhysicalOp="Index Scan" EstimatedTotalSubtreeCost="122.628">

    <OutputList>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    <ColumnReference Column="Uniq1002" />

    </OutputList>

    <RunTimeInformation>

    <RunTimeCountersPerThread Thread="0" ActualRows="31498488" ActualEndOfScans="1" ActualExecutions="1" />

    </RunTimeInformation>

    <IndexScan Ordered="false" ForcedIndex="false" NoExpandHint="false">

    <DefinedValues>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="primaryKey" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Column="offer" />

    </DefinedValue>

    <DefinedValue>

    <ColumnReference Column="Uniq1002" />

    </DefinedValue>

    </DefinedValues>

    <Object Database="[prod-live]" Schema="[schemA]" Table="[TableA]" Index="[PK_TableA]" />

    </IndexScan>

    </RelOp>

    </Hash>

    </RelOp>

    <ParameterList>

    <ColumnReference Column="@1" ParameterCompiledValue="'31519652'" ParameterRuntimeValue="'31519652'" />

    </ParameterList>

    </QueryPlan>

    </StmtSimple>

    </Statements>

    </Batch>

    </BatchSequence>

    </ShowPlanXML>

  • I can't open those.

    Can you save the plans as .sqlplan and upload those files?

    TIA.

  • files attached thanks!! didn't know I could attach files sorry

  • The estimates seem completely out of whack.

    #1 - Do you have the same indexes in both environements?

    #2 - Run update stats

  • Ninja's_RGR'us (5/10/2011)


    The estimates seem completely out of whack.

    #1 - Do you have the same indexes in both environements?

    #2 - Run update stats

    Yes same indexes and i have run update stats on that table there was no differences , the bad trace is from after a stats update.

  • Can you post the table and index definitions?

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • post the table? Afraid not there is sensitive information in it, what are you hoping to see from having the table would that help finding out why there is a difference between SP3 and SP4?

  • Not the data. The definition - Create table, create index

    May help to try and understand what the optimiser is thinking. It thinks that the useful index is missing, hard to say why without seeing what the table is defined as, and what indexes exist.

    Is the table and index definitions identical on both servers? (can you maybe post the definitions from both, just in case there's something subtle different)

    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

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Also maybe the output of DBCC SHOW_STATISTICS (TableA, IX_TableA_id) on both? Shouldn't be a problem with sensitive data, it's just the ID values.

    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

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • --Hope it's all there thanks for looking 🙂

    --SP4 BAD

    --Index

    CIX_TableA_offerclustered located on PRIMARYoffer

    IX_TableA_val3nonclustered located on PRIMARYval3

    IX_TableA_val4nonclustered located on PRIMARYval4

    IX_TableA_idnonclustered located on PRIMARYid

    PK_TableAnonclustered, unique, primary key located on PRIMARYprimaryKey

    --Table def

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    SET ANSI_PADDING ON

    GO

    CREATE TABLE [schemA].[TableA](

    [primaryKey] [int] IDENTITY(1,1) NOT NULL,

    [id] [varchar](15) NULL,

    [val1] [varchar](15) NULL,

    [val2] [varchar](15) NULL,

    [val3] [varchar](20) NULL,

    [val4] [varchar](20) NULL,

    [val5] [tinyint] NULL,

    [val6] [varchar](20) NULL,

    [val7] [varchar](50) NULL,

    [val8] [varchar](500) NULL,

    [val9] [tinyint] NULL,

    CONSTRAINT [PK_TableA] PRIMARY KEY NONCLUSTERED

    (

    [primaryKey] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]

    ) ON [PRIMARY]

    GO

    SET ANSI_PADDING OFF

    --table stats

    IX_TableA_idMay 11 2011 12:29AM314984882425471930.801755111.44844YES

    --SP3 GOOD

    --Index

    CIX_TableA_offerclustered located on PRIMARYoffer

    IX_TableA_val3nonclustered located on PRIMARYval3

    IX_TableA_val4nonclustered located on PRIMARYval4

    IX_TableA_idnonclustered located on PRIMARYid

    PK_TableAnonclustered, unique, primary key located on PRIMARYprimaryKey

    --Table def

    ET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    SET ANSI_PADDING ON

    GO

    CREATE TABLE [schemA].[TableA](

    [primaryKey] [int] IDENTITY(1,1) NOT NULL,

    [id] [varchar](15) NULL,

    [val1] [varchar](15) NULL,

    [val2] [varchar](15) NULL,

    [val3] [varchar](20) NULL,

    [val4] [varchar](20) NULL,

    [val5] [tinyint] NULL,

    [val6] [varchar](20) NULL,

    [val7] [varchar](50) NULL,

    [val8] [varchar](500) NULL,

    [val9] [tinyint] NULL,

    CONSTRAINT [PK_TableA] PRIMARY KEY NONCLUSTERED

    (

    [primaryKey] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]

    ) ON [PRIMARY]

    GO

    SET ANSI_PADDING OFF

    --table stats

    IX_TableA_idMay 11 2011 12:49AM323764452525901890.797369711.46685YES

  • Viewing 15 posts - 1 through 15 (of 22 total)

    You must be logged in to reply to this topic. Login to reply