Why does CCI creation on an empty table request a huge memory grant?












4















On a QA server with very low memory, I experienced error 8545 when creating clustered columnstore indexes on new tables in SQL Server 2016:




Error 8645: A time out occurred while waiting for memory resources to execute the query. Re-run the query.




I can easily reproduce a large requested memory grant on my local machine. For the following code:



DROP TABLE IF EXISTS dbo.MY_FIRST_FACT_TABLE;

CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL,
COL2 BIGINT NULL,
COL3 BIGINT NULL,
COL4 BIGINT NULL,
COL5 BIGINT NULL,
COL6 BIGINT NULL,
COL7 BIGINT NULL,
COL8 BIGINT NULL,
COL9 BIGINT NULL,
COL10 BIGINT NULL,
STRING1 VARCHAR(100) NULL,
STRING2 VARCHAR(100) NULL,
STRING3 VARCHAR(100) NULL,
STRING4 VARCHAR(100) NULL,
STRING5 VARCHAR(100) NULL
);

CREATE CLUSTERED COLUMNSTORE INDEX MY_FIRST_CCI ON dbo.MY_FIRST_FACT_TABLE;


I get a memory request of around 512 MB of memory. There is a warning for the excessive memory grant in the actual execution plan:



memory grant



Even though the query uses 0 KB of memeory it still might time out depending on other activity on the server. Why does SQL Server request so much memory? What can I do about it?










share|improve this question

























  • Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

    – Remus Rusanu
    May 1 '17 at 15:27











  • What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

    – Aaron Bertrand
    May 1 '17 at 19:41











  • @AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

    – Joe Obbish
    May 1 '17 at 20:19
















4















On a QA server with very low memory, I experienced error 8545 when creating clustered columnstore indexes on new tables in SQL Server 2016:




Error 8645: A time out occurred while waiting for memory resources to execute the query. Re-run the query.




I can easily reproduce a large requested memory grant on my local machine. For the following code:



DROP TABLE IF EXISTS dbo.MY_FIRST_FACT_TABLE;

CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL,
COL2 BIGINT NULL,
COL3 BIGINT NULL,
COL4 BIGINT NULL,
COL5 BIGINT NULL,
COL6 BIGINT NULL,
COL7 BIGINT NULL,
COL8 BIGINT NULL,
COL9 BIGINT NULL,
COL10 BIGINT NULL,
STRING1 VARCHAR(100) NULL,
STRING2 VARCHAR(100) NULL,
STRING3 VARCHAR(100) NULL,
STRING4 VARCHAR(100) NULL,
STRING5 VARCHAR(100) NULL
);

CREATE CLUSTERED COLUMNSTORE INDEX MY_FIRST_CCI ON dbo.MY_FIRST_FACT_TABLE;


I get a memory request of around 512 MB of memory. There is a warning for the excessive memory grant in the actual execution plan:



memory grant



Even though the query uses 0 KB of memeory it still might time out depending on other activity on the server. Why does SQL Server request so much memory? What can I do about it?










share|improve this question

























  • Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

    – Remus Rusanu
    May 1 '17 at 15:27











  • What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

    – Aaron Bertrand
    May 1 '17 at 19:41











  • @AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

    – Joe Obbish
    May 1 '17 at 20:19














4












4








4








On a QA server with very low memory, I experienced error 8545 when creating clustered columnstore indexes on new tables in SQL Server 2016:




Error 8645: A time out occurred while waiting for memory resources to execute the query. Re-run the query.




I can easily reproduce a large requested memory grant on my local machine. For the following code:



DROP TABLE IF EXISTS dbo.MY_FIRST_FACT_TABLE;

CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL,
COL2 BIGINT NULL,
COL3 BIGINT NULL,
COL4 BIGINT NULL,
COL5 BIGINT NULL,
COL6 BIGINT NULL,
COL7 BIGINT NULL,
COL8 BIGINT NULL,
COL9 BIGINT NULL,
COL10 BIGINT NULL,
STRING1 VARCHAR(100) NULL,
STRING2 VARCHAR(100) NULL,
STRING3 VARCHAR(100) NULL,
STRING4 VARCHAR(100) NULL,
STRING5 VARCHAR(100) NULL
);

CREATE CLUSTERED COLUMNSTORE INDEX MY_FIRST_CCI ON dbo.MY_FIRST_FACT_TABLE;


I get a memory request of around 512 MB of memory. There is a warning for the excessive memory grant in the actual execution plan:



memory grant



Even though the query uses 0 KB of memeory it still might time out depending on other activity on the server. Why does SQL Server request so much memory? What can I do about it?










share|improve this question
















On a QA server with very low memory, I experienced error 8545 when creating clustered columnstore indexes on new tables in SQL Server 2016:




Error 8645: A time out occurred while waiting for memory resources to execute the query. Re-run the query.




I can easily reproduce a large requested memory grant on my local machine. For the following code:



DROP TABLE IF EXISTS dbo.MY_FIRST_FACT_TABLE;

CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL,
COL2 BIGINT NULL,
COL3 BIGINT NULL,
COL4 BIGINT NULL,
COL5 BIGINT NULL,
COL6 BIGINT NULL,
COL7 BIGINT NULL,
COL8 BIGINT NULL,
COL9 BIGINT NULL,
COL10 BIGINT NULL,
STRING1 VARCHAR(100) NULL,
STRING2 VARCHAR(100) NULL,
STRING3 VARCHAR(100) NULL,
STRING4 VARCHAR(100) NULL,
STRING5 VARCHAR(100) NULL
);

CREATE CLUSTERED COLUMNSTORE INDEX MY_FIRST_CCI ON dbo.MY_FIRST_FACT_TABLE;


I get a memory request of around 512 MB of memory. There is a warning for the excessive memory grant in the actual execution plan:



memory grant



Even though the query uses 0 KB of memeory it still might time out depending on other activity on the server. Why does SQL Server request so much memory? What can I do about it?







sql-server sql-server-2016 columnstore memory-grant






share|improve this question















share|improve this question













share|improve this question




share|improve this question








edited 3 mins ago









Paul White

49.7k14262417




49.7k14262417










asked May 1 '17 at 15:24









Joe ObbishJoe Obbish

20.8k32882




20.8k32882













  • Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

    – Remus Rusanu
    May 1 '17 at 15:27











  • What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

    – Aaron Bertrand
    May 1 '17 at 19:41











  • @AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

    – Joe Obbish
    May 1 '17 at 20:19



















  • Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

    – Remus Rusanu
    May 1 '17 at 15:27











  • What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

    – Aaron Bertrand
    May 1 '17 at 19:41











  • @AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

    – Joe Obbish
    May 1 '17 at 20:19

















Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

– Remus Rusanu
May 1 '17 at 15:27





Looks like a bug to me. If the table has no allocation units, there should be no need to 'build' the CCI.

– Remus Rusanu
May 1 '17 at 15:27













What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

– Aaron Bertrand
May 1 '17 at 19:41





What makes me nervous is that if you can't afford this memory grant now, what will happen when there really is data in this table?

– Aaron Bertrand
May 1 '17 at 19:41













@AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

– Joe Obbish
May 1 '17 at 20:19





@AaronBertrand Good point, I edited the question and answer to make it clear that this was happening on a QA server with low memory. This is mostly a question out of curiosity. I agree that this is a sign that you'll have other problems.

– Joe Obbish
May 1 '17 at 20:19










1 Answer
1






active

oldest

votes


















3














There's a hint about this in the documentation for CCI query performance:




Plan for enough memory to create columnstore indexes in parallel



Creating a columnstore index is by default a parallel operation unless memory is constrained. Creating the index in parallel requires more memory than creating the index serially. When there is ample memory, creating a columnstore index takes on the order of 1.5 times as long as building a B-tree on the same columns.



The memory required for creating a columnstore index depends on the number of columns, the number of string columns, the degree of parallelism (DOP), and the characteristics of the data. For example, if your table has fewer than one million rows, SQL Server will use only one thread to create the columnstore index.




That quote suggests that the number of rows in the table matters for DOP but doesn't matter for the memory grant. The memory required also depends on the number of columns so let's test with a table with fewer columns to more easily see the expected difference in memory grant. I'm using this table and index definition:



DROP TABLE IF EXISTS dbo.MY_SECOND_FACT_TABLE;

CREATE TABLE dbo.MY_SECOND_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL
);

INSERT INTO dbo.MY_SECOND_FACT_TABLE WITH (TABLOCK) (ID, COL1)
SELECT TOP (0) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), NULL
FROM master..spt_values t1
CROSS JOIN master..spt_values t2
OPTION (MAXDOP 1);

CREATE CLUSTERED COLUMNSTORE INDEX MY_SECOND_CCI ON dbo.MY_SECOND_FACT_TABLE WITH (MAXDOP = 1);


Below are results from a few tests:



╔══════════════════╦════════════════╦═════════════════╗
║ REQUESTED_MAXDOP ║ NUMBER_OF_ROWS ║ MEMORY_GRANT_KB ║
╠══════════════════╬════════════════╬═════════════════╣
║ 1 ║ 0 ║ 89928 ║
║ 2 ║ 0 ║ 89928 ║
║ 1 ║ 2000000 ║ 89928 ║
║ 2 ║ 2000000 ║ 179896 ║
║ 1 ║ 5000000 ║ 89928 ║
║ 2 ║ 5000000 ║ 179896 ║
╚══════════════════╩════════════════╩═════════════════╝


With 0 rows the DOP is downgraded to 1, but otherwise the number of rows doesn't appear to matter for the memory grant. This is undoubtedbly a gross oversimplification, but perhaps SQL Server builds the CCI one rowgroup at a time per DOP and maintains the string dictionaries as it goes along. That sounds fine in practice and means that the memory grant won't scale with the number of rows in the table, but without a check for a very low number of rows SQL Server could request an excessive memory grant. The excessive memory grant wouldn't matter in most cases because the CREATE INDEX is so fast, but it can matter if SQL Server waits on the memory grant.



So now I have an idea of why the memory grant is so large, but what can be done about it? SQL Server 2014 introduced the syntax to define an index definition as part of the table definition. It is possible to write a single statement that creates both the table and the index:




INDEX index_name CLUSTERED COLUMNSTORE



Applies to: SQL Server 2014 through SQL Server 2016 and Azure SQL Database.



Specifies to store the entire table in columnar format with a clustered columnstore index. This always includes all columns in the table. The data is not sorted in alphabetical or numeric order since the rows are organized to gain columnstore compression benefits.




For the original table the syntax would look like this:



CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
ID BIGINT NOT NULL,
COL1 BIGINT NULL,
COL2 BIGINT NULL,
COL3 BIGINT NULL,
COL4 BIGINT NULL,
COL5 BIGINT NULL,
COL6 BIGINT NULL,
COL7 BIGINT NULL,
COL8 BIGINT NULL,
COL9 BIGINT NULL,
COL10 BIGINT NULL,
STRING1 VARCHAR(100) NULL,
STRING2 VARCHAR(100) NULL,
STRING3 VARCHAR(100) NULL,
STRING4 VARCHAR(100) NULL,
STRING5 VARCHAR(100) NULL,
INDEX MY_FIRST_CCI CLUSTERED COLUMNSTORE
);


A CREATE TABLE statement does not generate an actual plan so I can't immediately tell if this reduced the memory grant. I tried creating the table 1000 times while hammering the sys.dm_exec_query_memory_grants DMV but never got any results. That suggests that memory was not granted but isn't proof. I also tried extended events with query_memory_grant_usage and didn't get any results for the single CREATE TABLE statement.



Of course, the best way to test is to create the CCI the original workflow conditions with limited available memory. I did that and did not experience any memory timeouts.



I suppose it could be said that defining the CCI in the CREATE TABLE statement for a new table is a best practice. However, if your workload causes this error then changing the CREATE TABLE script probably isn't sufficient to address other problems that you'll run into, such as memory issues when you starting loading data into the CCIs.






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%2f172434%2fwhy-does-cci-creation-on-an-empty-table-request-a-huge-memory-grant%23new-answer', 'question_page');
    }
    );

    Post as a guest















    Required, but never shown

























    1 Answer
    1






    active

    oldest

    votes








    1 Answer
    1






    active

    oldest

    votes









    active

    oldest

    votes






    active

    oldest

    votes









    3














    There's a hint about this in the documentation for CCI query performance:




    Plan for enough memory to create columnstore indexes in parallel



    Creating a columnstore index is by default a parallel operation unless memory is constrained. Creating the index in parallel requires more memory than creating the index serially. When there is ample memory, creating a columnstore index takes on the order of 1.5 times as long as building a B-tree on the same columns.



    The memory required for creating a columnstore index depends on the number of columns, the number of string columns, the degree of parallelism (DOP), and the characteristics of the data. For example, if your table has fewer than one million rows, SQL Server will use only one thread to create the columnstore index.




    That quote suggests that the number of rows in the table matters for DOP but doesn't matter for the memory grant. The memory required also depends on the number of columns so let's test with a table with fewer columns to more easily see the expected difference in memory grant. I'm using this table and index definition:



    DROP TABLE IF EXISTS dbo.MY_SECOND_FACT_TABLE;

    CREATE TABLE dbo.MY_SECOND_FACT_TABLE (
    ID BIGINT NOT NULL,
    COL1 BIGINT NULL
    );

    INSERT INTO dbo.MY_SECOND_FACT_TABLE WITH (TABLOCK) (ID, COL1)
    SELECT TOP (0) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), NULL
    FROM master..spt_values t1
    CROSS JOIN master..spt_values t2
    OPTION (MAXDOP 1);

    CREATE CLUSTERED COLUMNSTORE INDEX MY_SECOND_CCI ON dbo.MY_SECOND_FACT_TABLE WITH (MAXDOP = 1);


    Below are results from a few tests:



    ╔══════════════════╦════════════════╦═════════════════╗
    ║ REQUESTED_MAXDOP ║ NUMBER_OF_ROWS ║ MEMORY_GRANT_KB ║
    ╠══════════════════╬════════════════╬═════════════════╣
    ║ 1 ║ 0 ║ 89928 ║
    ║ 2 ║ 0 ║ 89928 ║
    ║ 1 ║ 2000000 ║ 89928 ║
    ║ 2 ║ 2000000 ║ 179896 ║
    ║ 1 ║ 5000000 ║ 89928 ║
    ║ 2 ║ 5000000 ║ 179896 ║
    ╚══════════════════╩════════════════╩═════════════════╝


    With 0 rows the DOP is downgraded to 1, but otherwise the number of rows doesn't appear to matter for the memory grant. This is undoubtedbly a gross oversimplification, but perhaps SQL Server builds the CCI one rowgroup at a time per DOP and maintains the string dictionaries as it goes along. That sounds fine in practice and means that the memory grant won't scale with the number of rows in the table, but without a check for a very low number of rows SQL Server could request an excessive memory grant. The excessive memory grant wouldn't matter in most cases because the CREATE INDEX is so fast, but it can matter if SQL Server waits on the memory grant.



    So now I have an idea of why the memory grant is so large, but what can be done about it? SQL Server 2014 introduced the syntax to define an index definition as part of the table definition. It is possible to write a single statement that creates both the table and the index:




    INDEX index_name CLUSTERED COLUMNSTORE



    Applies to: SQL Server 2014 through SQL Server 2016 and Azure SQL Database.



    Specifies to store the entire table in columnar format with a clustered columnstore index. This always includes all columns in the table. The data is not sorted in alphabetical or numeric order since the rows are organized to gain columnstore compression benefits.




    For the original table the syntax would look like this:



    CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
    ID BIGINT NOT NULL,
    COL1 BIGINT NULL,
    COL2 BIGINT NULL,
    COL3 BIGINT NULL,
    COL4 BIGINT NULL,
    COL5 BIGINT NULL,
    COL6 BIGINT NULL,
    COL7 BIGINT NULL,
    COL8 BIGINT NULL,
    COL9 BIGINT NULL,
    COL10 BIGINT NULL,
    STRING1 VARCHAR(100) NULL,
    STRING2 VARCHAR(100) NULL,
    STRING3 VARCHAR(100) NULL,
    STRING4 VARCHAR(100) NULL,
    STRING5 VARCHAR(100) NULL,
    INDEX MY_FIRST_CCI CLUSTERED COLUMNSTORE
    );


    A CREATE TABLE statement does not generate an actual plan so I can't immediately tell if this reduced the memory grant. I tried creating the table 1000 times while hammering the sys.dm_exec_query_memory_grants DMV but never got any results. That suggests that memory was not granted but isn't proof. I also tried extended events with query_memory_grant_usage and didn't get any results for the single CREATE TABLE statement.



    Of course, the best way to test is to create the CCI the original workflow conditions with limited available memory. I did that and did not experience any memory timeouts.



    I suppose it could be said that defining the CCI in the CREATE TABLE statement for a new table is a best practice. However, if your workload causes this error then changing the CREATE TABLE script probably isn't sufficient to address other problems that you'll run into, such as memory issues when you starting loading data into the CCIs.






    share|improve this answer






























      3














      There's a hint about this in the documentation for CCI query performance:




      Plan for enough memory to create columnstore indexes in parallel



      Creating a columnstore index is by default a parallel operation unless memory is constrained. Creating the index in parallel requires more memory than creating the index serially. When there is ample memory, creating a columnstore index takes on the order of 1.5 times as long as building a B-tree on the same columns.



      The memory required for creating a columnstore index depends on the number of columns, the number of string columns, the degree of parallelism (DOP), and the characteristics of the data. For example, if your table has fewer than one million rows, SQL Server will use only one thread to create the columnstore index.




      That quote suggests that the number of rows in the table matters for DOP but doesn't matter for the memory grant. The memory required also depends on the number of columns so let's test with a table with fewer columns to more easily see the expected difference in memory grant. I'm using this table and index definition:



      DROP TABLE IF EXISTS dbo.MY_SECOND_FACT_TABLE;

      CREATE TABLE dbo.MY_SECOND_FACT_TABLE (
      ID BIGINT NOT NULL,
      COL1 BIGINT NULL
      );

      INSERT INTO dbo.MY_SECOND_FACT_TABLE WITH (TABLOCK) (ID, COL1)
      SELECT TOP (0) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), NULL
      FROM master..spt_values t1
      CROSS JOIN master..spt_values t2
      OPTION (MAXDOP 1);

      CREATE CLUSTERED COLUMNSTORE INDEX MY_SECOND_CCI ON dbo.MY_SECOND_FACT_TABLE WITH (MAXDOP = 1);


      Below are results from a few tests:



      ╔══════════════════╦════════════════╦═════════════════╗
      ║ REQUESTED_MAXDOP ║ NUMBER_OF_ROWS ║ MEMORY_GRANT_KB ║
      ╠══════════════════╬════════════════╬═════════════════╣
      ║ 1 ║ 0 ║ 89928 ║
      ║ 2 ║ 0 ║ 89928 ║
      ║ 1 ║ 2000000 ║ 89928 ║
      ║ 2 ║ 2000000 ║ 179896 ║
      ║ 1 ║ 5000000 ║ 89928 ║
      ║ 2 ║ 5000000 ║ 179896 ║
      ╚══════════════════╩════════════════╩═════════════════╝


      With 0 rows the DOP is downgraded to 1, but otherwise the number of rows doesn't appear to matter for the memory grant. This is undoubtedbly a gross oversimplification, but perhaps SQL Server builds the CCI one rowgroup at a time per DOP and maintains the string dictionaries as it goes along. That sounds fine in practice and means that the memory grant won't scale with the number of rows in the table, but without a check for a very low number of rows SQL Server could request an excessive memory grant. The excessive memory grant wouldn't matter in most cases because the CREATE INDEX is so fast, but it can matter if SQL Server waits on the memory grant.



      So now I have an idea of why the memory grant is so large, but what can be done about it? SQL Server 2014 introduced the syntax to define an index definition as part of the table definition. It is possible to write a single statement that creates both the table and the index:




      INDEX index_name CLUSTERED COLUMNSTORE



      Applies to: SQL Server 2014 through SQL Server 2016 and Azure SQL Database.



      Specifies to store the entire table in columnar format with a clustered columnstore index. This always includes all columns in the table. The data is not sorted in alphabetical or numeric order since the rows are organized to gain columnstore compression benefits.




      For the original table the syntax would look like this:



      CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
      ID BIGINT NOT NULL,
      COL1 BIGINT NULL,
      COL2 BIGINT NULL,
      COL3 BIGINT NULL,
      COL4 BIGINT NULL,
      COL5 BIGINT NULL,
      COL6 BIGINT NULL,
      COL7 BIGINT NULL,
      COL8 BIGINT NULL,
      COL9 BIGINT NULL,
      COL10 BIGINT NULL,
      STRING1 VARCHAR(100) NULL,
      STRING2 VARCHAR(100) NULL,
      STRING3 VARCHAR(100) NULL,
      STRING4 VARCHAR(100) NULL,
      STRING5 VARCHAR(100) NULL,
      INDEX MY_FIRST_CCI CLUSTERED COLUMNSTORE
      );


      A CREATE TABLE statement does not generate an actual plan so I can't immediately tell if this reduced the memory grant. I tried creating the table 1000 times while hammering the sys.dm_exec_query_memory_grants DMV but never got any results. That suggests that memory was not granted but isn't proof. I also tried extended events with query_memory_grant_usage and didn't get any results for the single CREATE TABLE statement.



      Of course, the best way to test is to create the CCI the original workflow conditions with limited available memory. I did that and did not experience any memory timeouts.



      I suppose it could be said that defining the CCI in the CREATE TABLE statement for a new table is a best practice. However, if your workload causes this error then changing the CREATE TABLE script probably isn't sufficient to address other problems that you'll run into, such as memory issues when you starting loading data into the CCIs.






      share|improve this answer




























        3












        3








        3







        There's a hint about this in the documentation for CCI query performance:




        Plan for enough memory to create columnstore indexes in parallel



        Creating a columnstore index is by default a parallel operation unless memory is constrained. Creating the index in parallel requires more memory than creating the index serially. When there is ample memory, creating a columnstore index takes on the order of 1.5 times as long as building a B-tree on the same columns.



        The memory required for creating a columnstore index depends on the number of columns, the number of string columns, the degree of parallelism (DOP), and the characteristics of the data. For example, if your table has fewer than one million rows, SQL Server will use only one thread to create the columnstore index.




        That quote suggests that the number of rows in the table matters for DOP but doesn't matter for the memory grant. The memory required also depends on the number of columns so let's test with a table with fewer columns to more easily see the expected difference in memory grant. I'm using this table and index definition:



        DROP TABLE IF EXISTS dbo.MY_SECOND_FACT_TABLE;

        CREATE TABLE dbo.MY_SECOND_FACT_TABLE (
        ID BIGINT NOT NULL,
        COL1 BIGINT NULL
        );

        INSERT INTO dbo.MY_SECOND_FACT_TABLE WITH (TABLOCK) (ID, COL1)
        SELECT TOP (0) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), NULL
        FROM master..spt_values t1
        CROSS JOIN master..spt_values t2
        OPTION (MAXDOP 1);

        CREATE CLUSTERED COLUMNSTORE INDEX MY_SECOND_CCI ON dbo.MY_SECOND_FACT_TABLE WITH (MAXDOP = 1);


        Below are results from a few tests:



        ╔══════════════════╦════════════════╦═════════════════╗
        ║ REQUESTED_MAXDOP ║ NUMBER_OF_ROWS ║ MEMORY_GRANT_KB ║
        ╠══════════════════╬════════════════╬═════════════════╣
        ║ 1 ║ 0 ║ 89928 ║
        ║ 2 ║ 0 ║ 89928 ║
        ║ 1 ║ 2000000 ║ 89928 ║
        ║ 2 ║ 2000000 ║ 179896 ║
        ║ 1 ║ 5000000 ║ 89928 ║
        ║ 2 ║ 5000000 ║ 179896 ║
        ╚══════════════════╩════════════════╩═════════════════╝


        With 0 rows the DOP is downgraded to 1, but otherwise the number of rows doesn't appear to matter for the memory grant. This is undoubtedbly a gross oversimplification, but perhaps SQL Server builds the CCI one rowgroup at a time per DOP and maintains the string dictionaries as it goes along. That sounds fine in practice and means that the memory grant won't scale with the number of rows in the table, but without a check for a very low number of rows SQL Server could request an excessive memory grant. The excessive memory grant wouldn't matter in most cases because the CREATE INDEX is so fast, but it can matter if SQL Server waits on the memory grant.



        So now I have an idea of why the memory grant is so large, but what can be done about it? SQL Server 2014 introduced the syntax to define an index definition as part of the table definition. It is possible to write a single statement that creates both the table and the index:




        INDEX index_name CLUSTERED COLUMNSTORE



        Applies to: SQL Server 2014 through SQL Server 2016 and Azure SQL Database.



        Specifies to store the entire table in columnar format with a clustered columnstore index. This always includes all columns in the table. The data is not sorted in alphabetical or numeric order since the rows are organized to gain columnstore compression benefits.




        For the original table the syntax would look like this:



        CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
        ID BIGINT NOT NULL,
        COL1 BIGINT NULL,
        COL2 BIGINT NULL,
        COL3 BIGINT NULL,
        COL4 BIGINT NULL,
        COL5 BIGINT NULL,
        COL6 BIGINT NULL,
        COL7 BIGINT NULL,
        COL8 BIGINT NULL,
        COL9 BIGINT NULL,
        COL10 BIGINT NULL,
        STRING1 VARCHAR(100) NULL,
        STRING2 VARCHAR(100) NULL,
        STRING3 VARCHAR(100) NULL,
        STRING4 VARCHAR(100) NULL,
        STRING5 VARCHAR(100) NULL,
        INDEX MY_FIRST_CCI CLUSTERED COLUMNSTORE
        );


        A CREATE TABLE statement does not generate an actual plan so I can't immediately tell if this reduced the memory grant. I tried creating the table 1000 times while hammering the sys.dm_exec_query_memory_grants DMV but never got any results. That suggests that memory was not granted but isn't proof. I also tried extended events with query_memory_grant_usage and didn't get any results for the single CREATE TABLE statement.



        Of course, the best way to test is to create the CCI the original workflow conditions with limited available memory. I did that and did not experience any memory timeouts.



        I suppose it could be said that defining the CCI in the CREATE TABLE statement for a new table is a best practice. However, if your workload causes this error then changing the CREATE TABLE script probably isn't sufficient to address other problems that you'll run into, such as memory issues when you starting loading data into the CCIs.






        share|improve this answer















        There's a hint about this in the documentation for CCI query performance:




        Plan for enough memory to create columnstore indexes in parallel



        Creating a columnstore index is by default a parallel operation unless memory is constrained. Creating the index in parallel requires more memory than creating the index serially. When there is ample memory, creating a columnstore index takes on the order of 1.5 times as long as building a B-tree on the same columns.



        The memory required for creating a columnstore index depends on the number of columns, the number of string columns, the degree of parallelism (DOP), and the characteristics of the data. For example, if your table has fewer than one million rows, SQL Server will use only one thread to create the columnstore index.




        That quote suggests that the number of rows in the table matters for DOP but doesn't matter for the memory grant. The memory required also depends on the number of columns so let's test with a table with fewer columns to more easily see the expected difference in memory grant. I'm using this table and index definition:



        DROP TABLE IF EXISTS dbo.MY_SECOND_FACT_TABLE;

        CREATE TABLE dbo.MY_SECOND_FACT_TABLE (
        ID BIGINT NOT NULL,
        COL1 BIGINT NULL
        );

        INSERT INTO dbo.MY_SECOND_FACT_TABLE WITH (TABLOCK) (ID, COL1)
        SELECT TOP (0) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)), NULL
        FROM master..spt_values t1
        CROSS JOIN master..spt_values t2
        OPTION (MAXDOP 1);

        CREATE CLUSTERED COLUMNSTORE INDEX MY_SECOND_CCI ON dbo.MY_SECOND_FACT_TABLE WITH (MAXDOP = 1);


        Below are results from a few tests:



        ╔══════════════════╦════════════════╦═════════════════╗
        ║ REQUESTED_MAXDOP ║ NUMBER_OF_ROWS ║ MEMORY_GRANT_KB ║
        ╠══════════════════╬════════════════╬═════════════════╣
        ║ 1 ║ 0 ║ 89928 ║
        ║ 2 ║ 0 ║ 89928 ║
        ║ 1 ║ 2000000 ║ 89928 ║
        ║ 2 ║ 2000000 ║ 179896 ║
        ║ 1 ║ 5000000 ║ 89928 ║
        ║ 2 ║ 5000000 ║ 179896 ║
        ╚══════════════════╩════════════════╩═════════════════╝


        With 0 rows the DOP is downgraded to 1, but otherwise the number of rows doesn't appear to matter for the memory grant. This is undoubtedbly a gross oversimplification, but perhaps SQL Server builds the CCI one rowgroup at a time per DOP and maintains the string dictionaries as it goes along. That sounds fine in practice and means that the memory grant won't scale with the number of rows in the table, but without a check for a very low number of rows SQL Server could request an excessive memory grant. The excessive memory grant wouldn't matter in most cases because the CREATE INDEX is so fast, but it can matter if SQL Server waits on the memory grant.



        So now I have an idea of why the memory grant is so large, but what can be done about it? SQL Server 2014 introduced the syntax to define an index definition as part of the table definition. It is possible to write a single statement that creates both the table and the index:




        INDEX index_name CLUSTERED COLUMNSTORE



        Applies to: SQL Server 2014 through SQL Server 2016 and Azure SQL Database.



        Specifies to store the entire table in columnar format with a clustered columnstore index. This always includes all columns in the table. The data is not sorted in alphabetical or numeric order since the rows are organized to gain columnstore compression benefits.




        For the original table the syntax would look like this:



        CREATE TABLE dbo.MY_FIRST_FACT_TABLE (
        ID BIGINT NOT NULL,
        COL1 BIGINT NULL,
        COL2 BIGINT NULL,
        COL3 BIGINT NULL,
        COL4 BIGINT NULL,
        COL5 BIGINT NULL,
        COL6 BIGINT NULL,
        COL7 BIGINT NULL,
        COL8 BIGINT NULL,
        COL9 BIGINT NULL,
        COL10 BIGINT NULL,
        STRING1 VARCHAR(100) NULL,
        STRING2 VARCHAR(100) NULL,
        STRING3 VARCHAR(100) NULL,
        STRING4 VARCHAR(100) NULL,
        STRING5 VARCHAR(100) NULL,
        INDEX MY_FIRST_CCI CLUSTERED COLUMNSTORE
        );


        A CREATE TABLE statement does not generate an actual plan so I can't immediately tell if this reduced the memory grant. I tried creating the table 1000 times while hammering the sys.dm_exec_query_memory_grants DMV but never got any results. That suggests that memory was not granted but isn't proof. I also tried extended events with query_memory_grant_usage and didn't get any results for the single CREATE TABLE statement.



        Of course, the best way to test is to create the CCI the original workflow conditions with limited available memory. I did that and did not experience any memory timeouts.



        I suppose it could be said that defining the CCI in the CREATE TABLE statement for a new table is a best practice. However, if your workload causes this error then changing the CREATE TABLE script probably isn't sufficient to address other problems that you'll run into, such as memory issues when you starting loading data into the CCIs.







        share|improve this answer














        share|improve this answer



        share|improve this answer








        edited May 1 '17 at 20:18

























        answered May 1 '17 at 15:24









        Joe ObbishJoe Obbish

        20.8k32882




        20.8k32882






























            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%2f172434%2fwhy-does-cci-creation-on-an-empty-table-request-a-huge-memory-grant%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

            SQL Server 17 - Attemping to backup to remote NAS but Access is denied

            Always On Availability groups resolving state after failover - Remote harden of transaction...

            Restoring from pg_dump with foreign key constraints