locked
SQL Server: SP become very slow, raw SQL query from the SP is still very fast RRS feed

  • Question

  • Hi!
    We are struggling with a strange problem: a SP become extremely slow when raw SQL is executed  fairly fast.

    1. we have  
    -MS SQL Server 2008 R2 Express Edition SP1   10.50.2500.0 with several databases on it.
    -a database (it's size is around 747Mb)
    -a stored procedure which takes different parameters and does select among multiple tables from the database.

            ALTER Procedure [dbo].[spGetMovieShortDataList](
                    @MediaID int = null,
                    @Rfa nvarchar(8) = null,
                    @LicenseWindow nvarchar(8) = null,
                    @OwnerID uniqueidentifier = null,
                    @LicenseType nvarchar(max) = null,
                    @PriceGroupID uniqueidentifier = null,
                    @Format nvarchar(max) = null,
                    @GenreID uniqueidentifier = null,
                    @Title nvarchar(max) = null,
                    @Actor nvarchar(max) = null,
                    @ProductionCountryID uniqueidentifier = null,
                    @DontReturnMoviesWithNoLicense bit = 0,
                    @DontReturnNotReadyMovies bit = 0,
                    @take int = 10,
                    @skip int = 0,
                    @order nvarchar(max) = null,
                    @asc bit = 1
                    )
                    as
                    begin
                        declare @SQLString nvarchar(max);
                        declare @ascending nvarchar(5);
                        declare @ParmDefinition nvarchar(max);
                        declare @now DateTime;
                        set @ParmDefinition='@MediaID int,
                    @Rfa nvarchar(8),
                    @LicenseWindow nvarchar(8),
                    @OwnerID uniqueidentifier,
                    @LicenseType nvarchar(max),
                    @PriceGroupID uniqueidentifier,
                    @Format nvarchar(max),
                    @GenreID uniqueidentifier,
                    @Title nvarchar(max),
                    @Actor nvarchar(max),
                    @ProductionCountryID uniqueidentifier,
                    @DontReturnMoviesWithNoLicense bit = 0,
                    @DontReturnNotReadyMovies bit = 0,
                    @take int,
                    @skip int,
                    @now DateTime';
                        set @ascending = case when @asc = 1 then 'ASC' else 'DESC' end  
                        set @now = GetDate();
                        set @SQLString='    
            
                        SELECT distinct m.ID, m.EpisodNo, m.MediaID, p.Dubbed, pf.Format, t.OriginalTitle
                        into #temp
                        FROM Media m
                        inner join Asset a1 on m.ID=a1.ID
                        inner join Asset a2 on a1.ParentID=a2.ID
                        inner join Asset a3 on a2.ParentID=a3.ID
                        inner join Title t on t.ID = a3.ID
                        inner join Product p on a2.ID = p.ID
                        left join AssetReady ar on ar.AssetID = a1.ID
                        left join License l on l.ProductID=p.ID
                        left join ProductFormat pf on pf.ID = p.Format '
                        + CASE WHEN @PriceGroupID IS NOT NULL THEN
                            'left join LicenseToPriceGroup lpg on lpg.LicenseID = l.ID ' ELSE '' END
                        + CASE WHEN @Title IS NOT NULL THEN
                            'left join LanguageAsset la on la.AssetID = m.ID ' ELSE '' END
                        + CASE WHEN @LicenseType IS NOT NULL THEN
                            'left join LicenseType lt on lt.ID=l.LicenseTypeID ' ELSE '' END
                        + CASE WHEN @Actor IS NOT NULL THEN
                            'left join Cast c on c.AssetID = a1.ID ' ELSE '' END
                        + CASE WHEN @GenreID IS NOT NULL THEN
                            'left join ListToCountryToAsset lca on lca.AssetID=a1.ID ' ELSE '' END
                        + CASE WHEN @ProductionCountryID IS NOT NULL THEN
                            'left join ProductionCountryToAsset pca on pca.AssetID=t.ID ' ELSE '' END
                        +
                        'where (
                        1 =    case  
                            when @Rfa = ''All'' then 1
                            when @Rfa = ''Ready'' then ar.Rfa
                            when @Rfa = ''NotReady'' and (l.TbaWindowStart is null OR l.TbaWindowStart = 0) and ar.Rfa = 0 and ar.SkipRfa = 0 then 1
                            when @Rfa = ''Skipped'' and ar.SkipRfa = 1 then 1
                        end) '
                        +
                        CASE WHEN @LicenseWindow IS NOT NULL THEN
                        'AND
                        1 = (case
                            when (@LicenseWindow = 1 And (l.WindowEnd < @now and l.TbaWindowEnd = 0)) then 1
                            when (@LicenseWindow = 2 And (l.TbaWindowStart = 0 and l.WindowStart < @now and (l.TbaWindowEnd = 1 or l.WindowEnd > @now))) then 1
                            when (@LicenseWindow = 4 And ((l.TbaWindowStart = 1 or l.WindowStart > @now) and (l.TbaWindowEnd = 1 or l.WindowEnd > @now))) then 1
                            when (@LicenseWindow = 3 And ((l.WindowEnd < @now and l.TbaWindowEnd = 0) or (l.TbaWindowStart = 0 and l.WindowStart < @now and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)))) then 1
                            when (@LicenseWindow = 5 And ((l.WindowEnd < @now and l.TbaWindowEnd = 0) or ((l.TbaWindowStart = 1 or l.WindowStart > @now) and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)))) then 1
                            when (@LicenseWindow = 6 And ((l.TbaWindowStart = 0 and l.WindowStart < @now and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)) or ((l.TbaWindowStart = 1 or l.WindowStart > @now) and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)))) then 1
                            when ((@LicenseWindow = 7 Or @LicenseWindow = 0) And ((l.WindowEnd < @now and l.TbaWindowEnd = 0) or (l.TbaWindowStart = 0 and l.WindowStart < @now and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)) or ((l.TbaWindowStart = 1 or l.WindowStart > @now) and (l.TbaWindowEnd = 1 or l.WindowEnd > @now)))) then 1
                        end) ' ELSE '' END
                        + CASE WHEN @OwnerID IS NOT NULL THEN
                            'AND (l.OwnerID = @OwnerID) ' ELSE '' END
                        + CASE WHEN @MediaID IS NOT NULL THEN
                            'AND (m.MediaID = @MediaID) ' ELSE '' END
                        + CASE WHEN @LicenseType IS NOT NULL THEN
                            'AND (lt.Name = @LicenseType) ' ELSE '' END
                        + CASE WHEN @PriceGroupID IS NOT NULL THEN
                            'AND (lpg.PriceGroupID = @PriceGroupID) ' ELSE '' END
                        + CASE WHEN @Format IS NOT NULL THEN
                            'AND (pf.Format = @Format) ' ELSE '' END
                        + CASE WHEN @GenreID IS NOT NULL THEN
                            'AND (lca.ListID = @GenreID) ' ELSE '' END
                        + CASE WHEN @DontReturnMoviesWithNoLicense = 1 THEN
                            'AND (l.ID is not null) ' ELSE '' END
                        + CASE WHEN @Title IS NOT NULL THEN
                            'AND (t.OriginalTitle like N''%' + @Title + '%'' OR la.LocalTitle like N''%' + @Title + '%'') ' ELSE '' END
                        + CASE WHEN @Actor IS NOT NULL THEN
                            'AND (rtrim(ltrim(replace(c.FirstName + '' '' + c.MiddleName + '' '' + c.LastName, ''  '', '' ''))) like ''%'' + rtrim(ltrim(replace(@Actor,''  '','' ''))) + ''%'') ' ELSE '' END
                        + CASE WHEN @DontReturnNotReadyMovies = 1 THEN
                            'AND ((ar.ID is not null) AND (ar.Ready = 1) AND (ar.CountryID = l.CountryID))' ELSE '' END
                        + CASE WHEN @ProductionCountryID IS NOT NULL THEN
                            'AND (pca.ProductionCountryID = @ProductionCountryID)' ELSE '' END
                            +                
                        '
                        select #temp.* ,ROW_NUMBER() over (order by ';
                        if @order = 'Title'
                        begin
                            set @SQLString = @SQLString + 'OriginalTitle';
                        end
                        else if @order = 'MediaID'
                        begin
                            set @SQLString = @SQLString + 'MediaID';
                        end
                        else
                        begin
                            set @SQLString = @SQLString + 'ID';
                        end
            
                        set @SQLString = @SQLString + ' ' + @ascending + '
                        ) rn
                        into #numbered
                        from #temp
            
                        declare @count int;
                        select @count = MAX(#numbered.rn) from #numbered
            
                        while (@skip >= @count )
                        begin
                            set @skip = @skip - @take;
                        end
            
                        select ID, MediaID, EpisodNo, Dubbed, Format, OriginalTitle, @count TotalCount from #numbered
                        where rn between @skip and @skip + @take
            
                        drop table #temp    
                        drop table #numbered';
            
                        execute sp_executesql @SQLString,@ParmDefinition, @MediaID, @Rfa, @LicenseWindow, @OwnerID, @LicenseType, @PriceGroupID, @Format, @GenreID,
                            @Title, @Actor, @ProductionCountryID, @DontReturnMoviesWithNoLicense,@DontReturnNotReadyMovies, @take, @skip, @now
                    end



    The stored procedure was working pretty good and fast (it's execution usually took 1-2 seconds).

    Example of call

        DBCC FREEPROCCACHE
        
        EXEC    value = [dbo].[spGetMovieShortDataList]
                @LicenseWindow =N'1',
                @Rfa = N'NotReady',        
                @DontReturnMoviesWithNoLicense = False,
                @DontReturnNotReadyMovies = True,
                @take = 20,
                @skip = 0,
                @asc = False,
                @order = N'ID'




    Basically during execution of the stored procedure the executed 3 SQL query, the first Select Into query takes 99% of time.
    This query is

        declare @now DateTime;
            
         set @now = GetDate();
        
        SELECT distinct m.ID, m.EpisodNo, m.MediaID, p.Dubbed, pf.Format, t.OriginalTitle
                        FROM Media m
                        inner join Asset a1 on m.ID=a1.ID
                        inner join Asset a2 on a1.ParentID=a2.ID
                        inner join Asset a3 on a2.ParentID=a3.ID
                        inner join Title t on t.ID = a3.ID
                        inner join Product p on a2.ID = p.ID
                        left join AssetReady ar on ar.AssetID = a1.ID
                        left join License l on l.ProductID=p.ID
                        left join ProductFormat pf on pf.ID = p.Format
                        
                        where
                        ((l.TbaWindowStart is null OR l.TbaWindowStart = 0) and ar.Rfa = 0 and ar.SkipRfa = 0 )
                        And (l.WindowEnd < @now and l.TbaWindowEnd = 0 )
                        AND ((ar.ID is not null) AND (ar.Ready = 1) AND (ar.CountryID = l.CountryID))
    


     

    2. This stored proc, after massive data update on the database (a lot tables and rows were affected by the update, however DB size was almost unchanged, now it is 752 ) become to work extremely slow. Now it takes from 20 to 90 seconds.

    3. If I take raw SQL query from the stored procedure - it is executed within 1-2 seconds.

    we've tried:

    a) the SP is created with parameters
    SET ANSI_NULLS ON    
    SET QUOTED_IDENTIFIER ON


    b) recreate the SP with parameter **with recompile**
    c) execute the SP after purging prod cache **DBCC FREEPROCCACHE**
    d) move part of where clauses into the join part
    e) reindex tables
    f) update statistics for the tables from the query using statements like **UPDATE STATISTICS Media WITH FULLSCAN**


    However the execution of the stored procedure is still >> 30 seconds.
    But if I run the SQL query which is generated by the SP - it is executed for less than 2 seconds.

    I've compared execution plans for SP and for the raw SQL - they are quite different. During execution of RAW SQL - the optimizer is using Merge Joins, but when we execute SP - it uses Hash Match (Inner Join), like there are no indexes.

    Execution Plan for RAW SQl - Fast
    Execution Plan for SP - Slow

    If someone knows what could it be - please help. Thanks in advance!

    Tuesday, June 3, 2014 1:21 PM

Answers

  • The solution is here:

    http://stackoverflow.com/questions/24016199/sql-server-stored-procedure-become-very-slow-raw-sql-query-is-still-very-fast

    I've added OPTION (OPTIMIZE FOR (@now UNKNOWN, @LicenseWindow UNKNOWN)) right after the first query in the SP and it become quite fast.

    • Proposed as answer by Naomi N Tuesday, June 3, 2014 4:41 PM
    • Marked as answer by Naomi N Tuesday, June 3, 2014 4:41 PM
    Tuesday, June 3, 2014 2:20 PM

All replies

  • The solution is here:

    http://stackoverflow.com/questions/24016199/sql-server-stored-procedure-become-very-slow-raw-sql-query-is-still-very-fast

    I've added OPTION (OPTIMIZE FOR (@now UNKNOWN, @LicenseWindow UNKNOWN)) right after the first query in the SP and it become quite fast.

    • Proposed as answer by Naomi N Tuesday, June 3, 2014 4:41 PM
    • Marked as answer by Naomi N Tuesday, June 3, 2014 4:41 PM
    Tuesday, June 3, 2014 2:20 PM
  • I noticed that you're not running the latest Service Pack for your SQL Server version.

    http://support.microsoft.com/kb/2527041

    With SQL Server you want to be on the latest SP.


    For every expert, there is an equal and opposite expert. - Becker's Law


    My blog


    My TechNet articles

    Tuesday, June 3, 2014 4:43 PM