Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix "Constant Folding" info in "Query Processing Architecture Guide" #3698

Closed
wants to merge 1 commit into from

Conversation

srutzky
Copy link
Contributor

@srutzky srutzky commented Nov 26, 2019

This PR fixes #3696 .

There are three mistakes in the Constant Folding section:

  1. There is a "note" that states:

    If the output type of the folding process is a large object type (text, image, nvarchar(max), varchar(max), or varbinary(max)), then SQL Server does not fold the expression.

    That list of datatypes is missing both NTEXT and XML.

  2. Under "Nonfoldable Expressions", it lists:

    • User-defined functions (both Transact-SQL and CLR)

    That was true until SQL Server 2012. Starting in that version (and still true as of SQL Server 2017), the following two items are foldable if they do not do any data access:

    • Deterministic scalar-valued CLR user-defined functions
    • Deterministic methods of CLR user-defined types

    Please see Behavior Changes in SQL Server 2012: Constant Folding for CLR User-Defined Functions and Methods

  3. The list of items under "Foldable Expressions" is missing the two SQLCLR items noted directly above.


Before executing any of the following tests, be sure to enable "Include Actual Execution Plan" (Control-M). After executing each test, just "View the XML Execution Plan".

The first two queries confirm expected behavior and indicate what it looks like when an expression is not folded.

SELECT TOP 1 CONVERT(NVARCHAR(50), 'bob') AS [Folded] FROM master.dbo.spt_values;
GO
/*
                <DefinedValues>
                  <DefinedValue>
                    <ColumnReference Column="Expr1004" />
                    <ScalarOperator ScalarString="N'bob'">
                      <Const ConstValue="N'bob'" />
                    </ScalarOperator>
                  </DefinedValue>
                </DefinedValues>
*/


SELECT TOP 1 CONVERT(NVARCHAR(MAX), 'bob') AS [NOT Folded-NVCmax] FROM master.dbo.spt_values;
GO
/*
 <DefinedValues>
   <DefinedValue>
     <ColumnReference Column="Expr1004" />
     <ScalarOperator ScalarString="CONVERT(nvarchar(max),'bob',0)">
       <Identifier>
         <ColumnReference Column="ConstExpr1005">
           <ScalarOperator>
             <Convert DataType="nvarchar(max)" Length="2147483647" Style="0" Implicit="false">
               <ScalarOperator>
                 <Const ConstValue="'bob'" />
               </ScalarOperator>
             </Convert>
           </ScalarOperator>
         </ColumnReference>
       </Identifier>
     </ScalarOperator>
   </DefinedValue>
 </DefinedValues>
*/

The next two queries test the other LOB types: NTEXT and XML.

-- Current DB's default collation cannot be Supplementary Character-Aware (collation
-- name has either "_SC", or "_140_" but not "_BIN*") else this will receive an error.
GO
SELECT TOP 1 CONVERT(NTEXT, 'bob') AS [NOT Folded-NTEXT] FROM master.dbo.spt_values;
GO
/*
                <DefinedValues>
                  <DefinedValue>
                    <ColumnReference Column="Expr1004" />
                    <ScalarOperator ScalarString="CONVERT(ntext,'bob',0)">
                      <Identifier>
                        <ColumnReference Column="ConstExpr1005">
                          <ScalarOperator>
                            <Convert DataType="ntext" Style="0" Implicit="false">
                              <ScalarOperator>
                                <Const ConstValue="'bob'" />
                              </ScalarOperator>
                            </Convert>
                          </ScalarOperator>
                        </ColumnReference>
                      </Identifier>
                    </ScalarOperator>
                  </DefinedValue>
                </DefinedValues>
*/


SELECT TOP 1 CONVERT(XML, 'bob') AS [NOT Folded-XML] FROM master.dbo.spt_values;
GO
/*
                <DefinedValues>
                  <DefinedValue>
                    <ColumnReference Column="Expr1004" />
                    <ScalarOperator ScalarString="CONVERT(xml,'bob',0)">
                      <Identifier>
                        <ColumnReference Column="ConstExpr1005">
                          <ScalarOperator>
                            <Convert DataType="xml" Style="0" Implicit="false">
                              <ScalarOperator>
                                <Const ConstValue="'bob'" />
                              </ScalarOperator>
                            </Convert>
                          </ScalarOperator>
                        </ColumnReference>
                      </Identifier>
                    </ScalarOperator>
                  </DefinedValue>
                </DefinedValues>
*/

For the following SQLCLR tests I use the SQL# library (that I wrote) because not only do I have it installed, but it is easy for anyone to download and install in order to duplicate these tests without needing to code or compile anything. Three of the four functions are available in the Free version, and the 4th function is a test function that isn't available in any public version (it's a rare instance of both being deterministic and doing data access).

The next query shows that SQLCLR UDFs can be folded.

SELECT SQL#.String_ToTitleCase4k(N'ŧ', N'') AS [Deterministic_NoDataAccess_NoLobTypes];
/*
            <RelOp ...>
              ...
              <ConstantScan>
                <Values>
                  <Row>
                    <ScalarOperator ScalarString="N'Ŧ'">
                      <Const ConstValue="N'Ŧ'" />
                    </ScalarOperator>
                  </Row>
                </Values>
              </ConstantScan>
            </RelOp>
*/

The next query shows that by changing the string datatypes to NVARCHAR(MAX), the same function (same .NET method, but different T-SQL wrapper object in order to change the datatypes) is no longer foldable.

SELECT SQL#.String_ToTitleCase(N'ŧ', N'') AS [Deterministic_NoDataAccess_LobType];
/*
  <RelOp ...>
    ...
    <ConstantScan>
      <Values>
        <Row>
          <ScalarOperator ScalarString="[SQL#_Full].[SQL#].[String_ToTitleCase](CONVERT_IMPLICIT(nvarchar(max),N'ŧ',0),N'')">
            <UserDefinedFunction FunctionName="[SQL#_Full].[SQL#].[String_ToTitleCase]" IsClrFunction="true">
              <ScalarOperator>
                <Convert DataType="nvarchar(max)" Length="2147483647" Style="0" Implicit="true">
                  <ScalarOperator>
                    <Const ConstValue="N'ŧ'" />
                  </ScalarOperator>
                </Convert>
              </ScalarOperator>
              <ScalarOperator>
                <Const ConstValue="N''" />
              </ScalarOperator>
              <CLRFunction Assembly="SQL#" Class="STRING" Method="ToTitleCase" />
            </UserDefinedFunction>
          </ScalarOperator>
        </Row>
      </Values>
    </ConstantScan>
  </RelOp>
*/

The next query shows that by not being marked as IsDeterministic=true, the UDF is not foldable.

SELECT SQL#.Math_RandomRange(NULL, 11, 200) AS [NonDeterministic_NoDataAccess_NoLobTypes];
/*
  <DefinedValues>
    <DefinedValue>
      <ColumnReference Column="Expr1000" />
      <ScalarOperator ScalarString="[SQL#_Full].[SQL#].[Math_RandomRange](NULL,(11),(200))">
        <UserDefinedFunction FunctionName="[SQL#_Full].[SQL#].[Math_RandomRange]" IsClrFunction="true">
          <ScalarOperator>
            <Const ConstValue="NULL" />
          </ScalarOperator>
          <ScalarOperator>
            <Const ConstValue="(11)" />
          </ScalarOperator>
          <ScalarOperator>
            <Const ConstValue="(200)" />
          </ScalarOperator>
          <CLRFunction Assembly="SQL#" Class="MATH" Method="RandomRange" />
        </UserDefinedFunction>
      </ScalarOperator>
    </DefinedValue>
  </DefinedValues>
*/

The next query shows that even with IsDeterministic=true and no LOB types, doing data access makes the UDF non-foldable.
Please note that TEST_GetCurrentServerName is not available in the Free version, or any version, of SQL#.

SELECT SQL#.TEST_GetCurrentServerName() AS [Deterministic_UserDataAccess_NoLobTypes];
/*
 <DefinedValues>
   <DefinedValue>
     <ColumnReference Column="Expr1000" />
     <ScalarOperator ScalarString="[SQL#_Full].[SQL#].[TEST_GetCurrentServerName]()">
       <UserDefinedFunction FunctionName="[SQL#_Full].[SQL#].[TEST_GetCurrentServerName]" IsClrFunction="true">
         <CLRFunction Assembly="SQL#_2" Class="TEST" Method="GetCurrentServerName" />
       </UserDefinedFunction>
     </ScalarOperator>
   </DefinedValue>
 </DefinedValues>
*/

Take care,
Solomon...
https://SqlQuantumLift.com/
https://SqlQuantumLeap.com/
https://SQLsharp.com/

1. Add datatypes NTEXT and XML to note regarding which output datatypes will prevent constant folding.

2. Clarify that SQLCLR UDFs and UDT methods, as of SQL Server 2012, _can_ be foldable, but only if they are marked as `IsDeterministic=true` and do not do any data access.

Full details, including example code to validate these changes, will be in the PR.
@PRMerger12
Copy link
Contributor

@srutzky : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@rothja
Copy link
Contributor

rothja commented Dec 20, 2019

@srutzky Thanks for taking the time to fix the article, and sorry for the delayed response. I need some time to get the product team to review and approve these changes. You have done a great job of documenting your findings, so thank you for your patience.

@MikeRayMSFT MikeRayMSFT requested review from pmasl and MikeRayMSFT and removed request for rothja December 20, 2019 18:59
@MikeRayMSFT MikeRayMSFT assigned MikeRayMSFT and unassigned rothja Dec 20, 2019
@pmasl
Copy link
Contributor

pmasl commented Dec 21, 2019 via email

@ktoliver
Copy link
Contributor

Hi @pmasl

Would you add a comment to show what action to take on this PR?

Merge the PR: #sign-off
Close the PR: #please-close
Wait on the PR: #hold-off

Thanks!

@rothja
Copy link
Contributor

rothja commented Feb 12, 2020

@pmasl Let me know if you had a chance to review this change. Thank you!

@ktoliver
Copy link
Contributor

I'm seeing the updates in master, so we'll close the PR.

@srutzky Thanks!

@ktoliver ktoliver closed this Feb 26, 2020
@srutzky
Copy link
Contributor Author

srutzky commented Feb 26, 2020

@ktoliver (and @rothja , @pmasl , and @MikeRayMSFT ): Yes, it looks like Pedro incorporated my suggested edits into a series of updates he made on this particular page. The commit containing my edits (made earlier today) is here:

909d1d2#diff-c7f5c629fe5c2e5e5339e2998eb14669

I am guessing that my commit for this PR was no longer easily mergable given the number of changes to this page since I submitted the PR.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
Projects
None yet
Development

Successfully merging this pull request may close these issues.

Constant Folding in Q.O.: CLR UDFs 𝑐𝑎𝑛, while NTEXT and XML output types 𝑤𝑜𝑛’𝑡
7 participants