Sort spills to tempdb due to varchar(max)












6















On a server with 32GB we are running SQL Server 2014 SP2 with a max memory of 25GB we have two tables, here you find a simplified structure of both tables:



CREATE TABLE [dbo].[Settings](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceId] [int] NULL,
[typeID] [int] NULL,
[remark] [varchar](max) NULL,
CONSTRAINT [PK_Settings] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[Resources](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceUID] [int] NULL,
CONSTRAINT [PK_Resources] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO


with following non-clustered indexes:



CREATE NONCLUSTERED INDEX [IX_UID] ON [dbo].[Resources]
(
[resourceUID] ASC
)

CREATE NONCLUSTERED INDEX [IX_Test] ON [dbo].[Settings]
(
[resourceId] ASC,
[typeID] ASC
)


The database is configured with compatibility level 120.



When I run this query there are spills to tempdb.
This is how I execute the query:



exec sp_executesql N'
select r.id,remark
FROM Resources r
inner join Settings on resourceid=r.id
where resourceUID=@UID
ORDER BY typeID',
N'@UID int',
@UID=38


If don't select the [remark] field no spills occurs. My first reaction was that the spills occurred due to the low number of estimated rows on the nested-loop operator.



So I add 5 datetime and 5 integer columns to the settings table and add them to my select statement. When I execute the query no spills are happening.



Why are the spills only happening when [remark] is selected? It has probably something to do with the fact that this is a varchar(max).
What can I do to avoid spilling to tempdb?










share|improve this question

























  • What happens when you add option(recompile) to the query that has spills?

    – Randi Vertongen
    2 hours ago













  • Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

    – Forrest
    1 hour ago











  • @randi: adding makes no difference

    – Frederik Vanderhaegen
    1 hour ago











  • May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

    – mustaccio
    1 hour ago











  • Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

    – Tony Hinkle
    1 hour ago
















6















On a server with 32GB we are running SQL Server 2014 SP2 with a max memory of 25GB we have two tables, here you find a simplified structure of both tables:



CREATE TABLE [dbo].[Settings](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceId] [int] NULL,
[typeID] [int] NULL,
[remark] [varchar](max) NULL,
CONSTRAINT [PK_Settings] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[Resources](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceUID] [int] NULL,
CONSTRAINT [PK_Resources] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO


with following non-clustered indexes:



CREATE NONCLUSTERED INDEX [IX_UID] ON [dbo].[Resources]
(
[resourceUID] ASC
)

CREATE NONCLUSTERED INDEX [IX_Test] ON [dbo].[Settings]
(
[resourceId] ASC,
[typeID] ASC
)


The database is configured with compatibility level 120.



When I run this query there are spills to tempdb.
This is how I execute the query:



exec sp_executesql N'
select r.id,remark
FROM Resources r
inner join Settings on resourceid=r.id
where resourceUID=@UID
ORDER BY typeID',
N'@UID int',
@UID=38


If don't select the [remark] field no spills occurs. My first reaction was that the spills occurred due to the low number of estimated rows on the nested-loop operator.



So I add 5 datetime and 5 integer columns to the settings table and add them to my select statement. When I execute the query no spills are happening.



Why are the spills only happening when [remark] is selected? It has probably something to do with the fact that this is a varchar(max).
What can I do to avoid spilling to tempdb?










share|improve this question

























  • What happens when you add option(recompile) to the query that has spills?

    – Randi Vertongen
    2 hours ago













  • Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

    – Forrest
    1 hour ago











  • @randi: adding makes no difference

    – Frederik Vanderhaegen
    1 hour ago











  • May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

    – mustaccio
    1 hour ago











  • Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

    – Tony Hinkle
    1 hour ago














6












6








6


1






On a server with 32GB we are running SQL Server 2014 SP2 with a max memory of 25GB we have two tables, here you find a simplified structure of both tables:



CREATE TABLE [dbo].[Settings](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceId] [int] NULL,
[typeID] [int] NULL,
[remark] [varchar](max) NULL,
CONSTRAINT [PK_Settings] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[Resources](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceUID] [int] NULL,
CONSTRAINT [PK_Resources] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO


with following non-clustered indexes:



CREATE NONCLUSTERED INDEX [IX_UID] ON [dbo].[Resources]
(
[resourceUID] ASC
)

CREATE NONCLUSTERED INDEX [IX_Test] ON [dbo].[Settings]
(
[resourceId] ASC,
[typeID] ASC
)


The database is configured with compatibility level 120.



When I run this query there are spills to tempdb.
This is how I execute the query:



exec sp_executesql N'
select r.id,remark
FROM Resources r
inner join Settings on resourceid=r.id
where resourceUID=@UID
ORDER BY typeID',
N'@UID int',
@UID=38


If don't select the [remark] field no spills occurs. My first reaction was that the spills occurred due to the low number of estimated rows on the nested-loop operator.



So I add 5 datetime and 5 integer columns to the settings table and add them to my select statement. When I execute the query no spills are happening.



Why are the spills only happening when [remark] is selected? It has probably something to do with the fact that this is a varchar(max).
What can I do to avoid spilling to tempdb?










share|improve this question
















On a server with 32GB we are running SQL Server 2014 SP2 with a max memory of 25GB we have two tables, here you find a simplified structure of both tables:



CREATE TABLE [dbo].[Settings](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceId] [int] NULL,
[typeID] [int] NULL,
[remark] [varchar](max) NULL,
CONSTRAINT [PK_Settings] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[Resources](
[id] [int] IDENTITY(1,1) NOT NULL,
[resourceUID] [int] NULL,
CONSTRAINT [PK_Resources] PRIMARY KEY CLUSTERED ([id] ASC)
) ON [PRIMARY]
GO


with following non-clustered indexes:



CREATE NONCLUSTERED INDEX [IX_UID] ON [dbo].[Resources]
(
[resourceUID] ASC
)

CREATE NONCLUSTERED INDEX [IX_Test] ON [dbo].[Settings]
(
[resourceId] ASC,
[typeID] ASC
)


The database is configured with compatibility level 120.



When I run this query there are spills to tempdb.
This is how I execute the query:



exec sp_executesql N'
select r.id,remark
FROM Resources r
inner join Settings on resourceid=r.id
where resourceUID=@UID
ORDER BY typeID',
N'@UID int',
@UID=38


If don't select the [remark] field no spills occurs. My first reaction was that the spills occurred due to the low number of estimated rows on the nested-loop operator.



So I add 5 datetime and 5 integer columns to the settings table and add them to my select statement. When I execute the query no spills are happening.



Why are the spills only happening when [remark] is selected? It has probably something to do with the fact that this is a varchar(max).
What can I do to avoid spilling to tempdb?







sql-server query-performance tempdb cardinality-estimates






share|improve this question















share|improve this question













share|improve this question




share|improve this question








edited 1 hour ago







Frederik Vanderhaegen

















asked 2 hours ago









Frederik VanderhaegenFrederik Vanderhaegen

6471316




6471316













  • What happens when you add option(recompile) to the query that has spills?

    – Randi Vertongen
    2 hours ago













  • Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

    – Forrest
    1 hour ago











  • @randi: adding makes no difference

    – Frederik Vanderhaegen
    1 hour ago











  • May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

    – mustaccio
    1 hour ago











  • Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

    – Tony Hinkle
    1 hour ago



















  • What happens when you add option(recompile) to the query that has spills?

    – Randi Vertongen
    2 hours ago













  • Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

    – Forrest
    1 hour ago











  • @randi: adding makes no difference

    – Frederik Vanderhaegen
    1 hour ago











  • May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

    – mustaccio
    1 hour ago











  • Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

    – Tony Hinkle
    1 hour ago

















What happens when you add option(recompile) to the query that has spills?

– Randi Vertongen
2 hours ago







What happens when you add option(recompile) to the query that has spills?

– Randi Vertongen
2 hours ago















Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

– Forrest
1 hour ago





Here's a dbfiddle to help with getting a repro. It currently has no data, and thus produces a different plan. If you want to adjust the fiddle and post a new link, it will help us propose solutions.

– Forrest
1 hour ago













@randi: adding makes no difference

– Frederik Vanderhaegen
1 hour ago





@randi: adding makes no difference

– Frederik Vanderhaegen
1 hour ago













May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

– mustaccio
1 hour ago





May be you can try select r.id, LEFT(remark, 512) (or whatever sensible substring length might be).

– mustaccio
1 hour ago













Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

– Tony Hinkle
1 hour ago





Is it actually causing a performance issue? If it only spills a tiny amount of data to tempdb, I think it will all be done in memory and it's really not a problem...

– Tony Hinkle
1 hour ago










2 Answers
2






active

oldest

votes


















6














There are going to be several possible workarounds here.



You can manually adjust the memory grant, though I probably wouldn't go that route.



You can also use a CTE and TOP to push the sort lower, before grabbing the max length column. It will look something like below.



WITH CTE AS (
SELECT TOP 1000000000 r.ID, s.ID AS ID2, s.typeID
FROM Resources r
inner join Settings s on resourceid=r.id
where resourceUID=@UID
ORDER BY s.typeID
)
SELECT c.ID, ca.remark
FROM CTE c
CROSS APPLY (SELECT remark FROM dbo.Settings s WHERE s.id = c.ID2) ca(remark)
ORDER BY c.typeID


Proof-of-concept dbfiddle here
Sample data would still be appreciated!






share|improve this answer































    4















    Why are the spills only happening when [remark] is selected?




    The spill is happening when you include that column because you don't get a big enough memory grant for the large string data being sorted.



    You don't get a big enough memory grant because the actual number of rows is 10x more than the estimated number of rows (1,302 actual vs 126 estimated).



    Why is the estimate off? Why does SQL Server think there's only one row in dbo.Settings with a resourceid of 38?



    It could be a statistics issue, which you can check by running DBCC SHOW_STATISTICS('dbo.Settings', 'IX_Test') and see the counts for that histogram step. But the execution plan seems to indicate that the stats are as complete and up-to-date as they could be.



    Since stats aren't helping, your best bet is probably a query rewrite - which Forrest has covered in his answer.






    share|improve this answer























      Your Answer








      StackExchange.ready(function() {
      var channelOptions = {
      tags: "".split(" "),
      id: "182"
      };
      initTagRenderer("".split(" "), "".split(" "), channelOptions);

      StackExchange.using("externalEditor", function() {
      // Have to fire editor after snippets, if snippets enabled
      if (StackExchange.settings.snippets.snippetsEnabled) {
      StackExchange.using("snippets", function() {
      createEditor();
      });
      }
      else {
      createEditor();
      }
      });

      function createEditor() {
      StackExchange.prepareEditor({
      heartbeatType: 'answer',
      autoActivateHeartbeat: false,
      convertImagesToLinks: false,
      noModals: true,
      showLowRepImageUploadWarning: true,
      reputationToPostImages: null,
      bindNavPrevention: true,
      postfix: "",
      imageUploader: {
      brandingHtml: "Powered by u003ca class="icon-imgur-white" href="https://imgur.com/"u003eu003c/au003e",
      contentPolicyHtml: "User contributions licensed under u003ca href="https://creativecommons.org/licenses/by-sa/3.0/"u003ecc by-sa 3.0 with attribution requiredu003c/au003e u003ca href="https://stackoverflow.com/legal/content-policy"u003e(content policy)u003c/au003e",
      allowUrls: true
      },
      onDemand: true,
      discardSelector: ".discard-answer"
      ,immediatelyShowMarkdownHelp:true
      });


      }
      });














      draft saved

      draft discarded


















      StackExchange.ready(
      function () {
      StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fdba.stackexchange.com%2fquestions%2f227288%2fsort-spills-to-tempdb-due-to-varcharmax%23new-answer', 'question_page');
      }
      );

      Post as a guest















      Required, but never shown

























      2 Answers
      2






      active

      oldest

      votes








      2 Answers
      2






      active

      oldest

      votes









      active

      oldest

      votes






      active

      oldest

      votes









      6














      There are going to be several possible workarounds here.



      You can manually adjust the memory grant, though I probably wouldn't go that route.



      You can also use a CTE and TOP to push the sort lower, before grabbing the max length column. It will look something like below.



      WITH CTE AS (
      SELECT TOP 1000000000 r.ID, s.ID AS ID2, s.typeID
      FROM Resources r
      inner join Settings s on resourceid=r.id
      where resourceUID=@UID
      ORDER BY s.typeID
      )
      SELECT c.ID, ca.remark
      FROM CTE c
      CROSS APPLY (SELECT remark FROM dbo.Settings s WHERE s.id = c.ID2) ca(remark)
      ORDER BY c.typeID


      Proof-of-concept dbfiddle here
      Sample data would still be appreciated!






      share|improve this answer




























        6














        There are going to be several possible workarounds here.



        You can manually adjust the memory grant, though I probably wouldn't go that route.



        You can also use a CTE and TOP to push the sort lower, before grabbing the max length column. It will look something like below.



        WITH CTE AS (
        SELECT TOP 1000000000 r.ID, s.ID AS ID2, s.typeID
        FROM Resources r
        inner join Settings s on resourceid=r.id
        where resourceUID=@UID
        ORDER BY s.typeID
        )
        SELECT c.ID, ca.remark
        FROM CTE c
        CROSS APPLY (SELECT remark FROM dbo.Settings s WHERE s.id = c.ID2) ca(remark)
        ORDER BY c.typeID


        Proof-of-concept dbfiddle here
        Sample data would still be appreciated!






        share|improve this answer


























          6












          6








          6







          There are going to be several possible workarounds here.



          You can manually adjust the memory grant, though I probably wouldn't go that route.



          You can also use a CTE and TOP to push the sort lower, before grabbing the max length column. It will look something like below.



          WITH CTE AS (
          SELECT TOP 1000000000 r.ID, s.ID AS ID2, s.typeID
          FROM Resources r
          inner join Settings s on resourceid=r.id
          where resourceUID=@UID
          ORDER BY s.typeID
          )
          SELECT c.ID, ca.remark
          FROM CTE c
          CROSS APPLY (SELECT remark FROM dbo.Settings s WHERE s.id = c.ID2) ca(remark)
          ORDER BY c.typeID


          Proof-of-concept dbfiddle here
          Sample data would still be appreciated!






          share|improve this answer













          There are going to be several possible workarounds here.



          You can manually adjust the memory grant, though I probably wouldn't go that route.



          You can also use a CTE and TOP to push the sort lower, before grabbing the max length column. It will look something like below.



          WITH CTE AS (
          SELECT TOP 1000000000 r.ID, s.ID AS ID2, s.typeID
          FROM Resources r
          inner join Settings s on resourceid=r.id
          where resourceUID=@UID
          ORDER BY s.typeID
          )
          SELECT c.ID, ca.remark
          FROM CTE c
          CROSS APPLY (SELECT remark FROM dbo.Settings s WHERE s.id = c.ID2) ca(remark)
          ORDER BY c.typeID


          Proof-of-concept dbfiddle here
          Sample data would still be appreciated!







          share|improve this answer












          share|improve this answer



          share|improve this answer










          answered 1 hour ago









          ForrestForrest

          1,932517




          1,932517

























              4















              Why are the spills only happening when [remark] is selected?




              The spill is happening when you include that column because you don't get a big enough memory grant for the large string data being sorted.



              You don't get a big enough memory grant because the actual number of rows is 10x more than the estimated number of rows (1,302 actual vs 126 estimated).



              Why is the estimate off? Why does SQL Server think there's only one row in dbo.Settings with a resourceid of 38?



              It could be a statistics issue, which you can check by running DBCC SHOW_STATISTICS('dbo.Settings', 'IX_Test') and see the counts for that histogram step. But the execution plan seems to indicate that the stats are as complete and up-to-date as they could be.



              Since stats aren't helping, your best bet is probably a query rewrite - which Forrest has covered in his answer.






              share|improve this answer




























                4















                Why are the spills only happening when [remark] is selected?




                The spill is happening when you include that column because you don't get a big enough memory grant for the large string data being sorted.



                You don't get a big enough memory grant because the actual number of rows is 10x more than the estimated number of rows (1,302 actual vs 126 estimated).



                Why is the estimate off? Why does SQL Server think there's only one row in dbo.Settings with a resourceid of 38?



                It could be a statistics issue, which you can check by running DBCC SHOW_STATISTICS('dbo.Settings', 'IX_Test') and see the counts for that histogram step. But the execution plan seems to indicate that the stats are as complete and up-to-date as they could be.



                Since stats aren't helping, your best bet is probably a query rewrite - which Forrest has covered in his answer.






                share|improve this answer


























                  4












                  4








                  4








                  Why are the spills only happening when [remark] is selected?




                  The spill is happening when you include that column because you don't get a big enough memory grant for the large string data being sorted.



                  You don't get a big enough memory grant because the actual number of rows is 10x more than the estimated number of rows (1,302 actual vs 126 estimated).



                  Why is the estimate off? Why does SQL Server think there's only one row in dbo.Settings with a resourceid of 38?



                  It could be a statistics issue, which you can check by running DBCC SHOW_STATISTICS('dbo.Settings', 'IX_Test') and see the counts for that histogram step. But the execution plan seems to indicate that the stats are as complete and up-to-date as they could be.



                  Since stats aren't helping, your best bet is probably a query rewrite - which Forrest has covered in his answer.






                  share|improve this answer














                  Why are the spills only happening when [remark] is selected?




                  The spill is happening when you include that column because you don't get a big enough memory grant for the large string data being sorted.



                  You don't get a big enough memory grant because the actual number of rows is 10x more than the estimated number of rows (1,302 actual vs 126 estimated).



                  Why is the estimate off? Why does SQL Server think there's only one row in dbo.Settings with a resourceid of 38?



                  It could be a statistics issue, which you can check by running DBCC SHOW_STATISTICS('dbo.Settings', 'IX_Test') and see the counts for that histogram step. But the execution plan seems to indicate that the stats are as complete and up-to-date as they could be.



                  Since stats aren't helping, your best bet is probably a query rewrite - which Forrest has covered in his answer.







                  share|improve this answer












                  share|improve this answer



                  share|improve this answer










                  answered 1 hour ago









                  jadarnel27jadarnel27

                  4,1371331




                  4,1371331






























                      draft saved

                      draft discarded




















































                      Thanks for contributing an answer to Database Administrators Stack Exchange!


                      • Please be sure to answer the question. Provide details and share your research!

                      But avoid



                      • Asking for help, clarification, or responding to other answers.

                      • Making statements based on opinion; back them up with references or personal experience.


                      To learn more, see our tips on writing great answers.




                      draft saved


                      draft discarded














                      StackExchange.ready(
                      function () {
                      StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fdba.stackexchange.com%2fquestions%2f227288%2fsort-spills-to-tempdb-due-to-varcharmax%23new-answer', 'question_page');
                      }
                      );

                      Post as a guest















                      Required, but never shown





















































                      Required, but never shown














                      Required, but never shown












                      Required, but never shown







                      Required, but never shown

































                      Required, but never shown














                      Required, but never shown












                      Required, but never shown







                      Required, but never shown







                      Popular posts from this blog

                      Reichsarbeitsdienst

                      Statuo de Libereco

                      Tanganjiko