sqlsql-serverdynamic-sqlsql-server-2016memory-optimized-tables

Select into memory optimised table


I have a stored procedure that will convert some dynamic sql into either a temp table or view dependant on a database setting. This is used to "tune" database functionality between different clients depending on size of data, i.e. temp table takes longer to create but takes longer to setup, a view creates quickly but takes slightly longer to read.

I am looking at expanding this out to include an option for memory optimised tables but can't see how to use a memory optimised table without declaring it fully first.

My code at the moment would be of a format like:

SELECT TOP 10 *
INTO FavoriteCustomers
FROM Customers
ORDER BY Spend DESC

As you can see I'm not declaring the table, just using select into. Is there any way I can SELECT INTO a memory optimised table? I can use:

sys.dm_exec_describe_first_result_set(@mySQLhere)

Which gives me a column definition for the TSQL I pass in. Then use this info to pre-build the table and insert into it, but I'm hoping for a neater method if possible.

Does anyone have any solutions? Search just takes me down the road of how to add data to a MOT not MOT creation as part of a select.

I understand this may not be possible, and I do have the work around described, I just feel I may be missing a better option here.

Currently using multiple servers, MOT functions only being implemented on SQL2016.

Many thanks in advance.


Solution

  • CREATE PROC [engine].[usp_CreateDynamicContent]
        @ContentName AS NVARCHAR(MAX)
    ,   @NTS_SessionID NVARCHAR(MAX)
    ,   @SelectSQL NVARCHAR(MAX)
    ,   @PrimaryKeyField NVARCHAR(MAX) = NULL
    ,   @NonClusteredIndexField NVARCHAR(MAX) = NULL
    ,   @debug BIT = 0
    AS
        BEGIN
    
            DECLARE @ContentType AS NVARCHAR(MAX)
            DECLARE @dcName AS NVARCHAR(MAX)
            DECLARE @strSQL AS NVARCHAR(MAX)
    
            SET @dcName = 'tmp.dc_' + @ContentName + '_' + @NTS_SessionID
    
            IF OBJECT_ID(@dcName, 'V') IS NOT NULL /* Drop the view if it exists */
                BEGIN
                    SET @strSQL = 'DROP VIEW ' + @dcName
                    IF @debug = 1
                        PRINT (@strSQL)
                    EXEC (@strSQL)
                END
    
            IF OBJECT_ID(@dcName) IS NOT NULL /* Drop the table if it exists */
                BEGIN
                    SET @strSQL = 'DROP TABLE ' + @dcName
                    IF @debug = 1
                        PRINT (@strSQL)
                    EXEC (@strSQL)
                END
    
            /* This is my database listing types for each table. */
            SELECT  @ContentType = ContentType
            FROM    guid.DynamicContents
            WHERE   ContentName = @ContentName
    
            IF @ContentType = 'VIEW'
                BEGIN
                    SET @strSQL = 'CREATE VIEW ' + @dcName + ' AS' + CHAR(13) + @SelectSQL
                    IF @debug = 1
                        PRINT (@strSQL)
                    EXEC (@strSQL)
                END
            ELSE
                IF @ContentType IN ('TABLE', 'MOT')
                    BEGIN
                        SET @strSQL = ''
                        SELECT  @strSQL = @strSQL + ',' + CHAR(10) + '[' + name + '] ' + system_type_name + CASE WHEN @PrimaryKeyField IS NOT NULL
                                                                                                                      AND @ContentType = 'MOT' THEN ' NOT NULL PRIMARY KEY NONCLUSTERED'
                                                                                                                 ELSE ''
                                                                                                            END + CHAR(13)
                        FROM    sys.dm_exec_describe_first_result_set(@SelectSQL, NULL, 0)
                        SET @strSQL = STUFF(@strSQL, 1, 1, 'CREATE TABLE ' + @dcName + '(')
    
                        IF @PrimaryKeyField IS NOT NULL
                            AND @ContentType = 'TABLE'
                            BEGIN
                                SET @strSQL = @strSQL + CHAR(10) + ',CONSTRAINT pk_' + @ContentName + '_' + @NTS_SessionID + ' PRIMARY KEY (' + @PrimaryKeyField + ')' + CHAR(10)
                            END
    
                        SET @strSQL = @strSQL + ')'
                        IF @debug = 1
                            PRINT (@strSQL)
                        EXEC (@strSQL)
    
                        IF @NonClusteredIndexField IS NOT NULL
                            AND @ContentType = 'TABLE'
                            BEGIN
                                SET @strSQL = 'CREATE NONCLUSTERED INDEX ix_' + @ContentName + '_' + @NonClusteredIndexField + ' ON ' + @dcName + ' (' + @NonClusteredIndexField + ')'
                                IF @debug = 1
                                    PRINT (@strSQL)
                                EXEC (@strSQL)
                            END
    
                        /* This section added in as I use cte's quite a lot */
                        IF @SelectSQL LIKE '%/* INSERT HERE */%'
                            BEGIN
                                SET @strSQL = REPLACE(@SelectSQL, '/* INSERT HERE */', 'INSERT INTO ' + @dcName)
                            END
                        ELSE
                            BEGIN
                                SET @strSQL = 'INSERT INTO ' + @dcName + CHAR(13) + @SelectSQL 
                            END
                        IF @debug = 1
                            PRINT (@strSQL)
                        EXEC (@strSQL)
                    END
    
        END