TechNet
Export (0) Print
Expand All

Transact-SQL Constructs Not Supported by In-Memory OLTP

 

Applies To: SQL Server 2016

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2016)yesAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Memory-optimized tables, natively compiled stored procedures, and user-defined functions do not support the full Transact-SQL surface area that is supported by disk-based tables, interpreted Transact-SQL stored procedures, and user-defined functions. When attempting to use one of the unsupported features, the server returns an error.

The error message text mentions the type of Transact-SQL statement (feature, operation, option, for example) and well as the name of the feature or Transact-SQL keyword. Most unsupported features will return error 10794, with the error message text indicating the unsupported feature. The following tables list the Transact-SQL features and keywords that can appear in the error message text, as well as the corrective action to resolve the error.

For more information on supported features with memory-optimized tables and natively compiled stored procedures, see:

The following table lists the Transact-SQL features that are not supported, and the keywords that can appear in the message text of an error involving an In-Memory OLTP database. The table also lists the resolution for the error.

TypeNameResolution
OptionAUTO_CLOSEThe database option AUTO_CLOSE=ON is not supported with databases that have a MEMORY_OPTIMIZED_DATA filegroup.
OptionATTACH_REBUILD_LOGThe CREATE database option ATTACH_REBUILD_LOG is not supported with databases that have a MEMORY_OPTIMIZED_DATA filegroup.
FeatureDATABASE SNAPSHOTCreating database snapshots is not supported with databases that have a MEMORY_OPTIMIZED_DATA filegroup.
FeatureReplication using the sync_method 'database snapshot' or 'database snapshot character'Replication using the sync_method 'database snapshot' or 'database snapshot character' is not supported with databases that have a MEMORY_OPTIMIZED_DATA filegroup.
FeatureDBCC CHECKDB

DBCC CHECKTABLE
DBCC CHECKDB skips the memory-optimized tables in the database.

DBCC CHECKTABLE will fail for memory-optimized tables.

The following table lists the Transact-SQL features that are not supported, and the keywords that can appear in the message text of an error involving a memory-optimized table. The table also lists the resolution for the error.

TypeNameResolution
FeatureONMemory-optimized tables cannot be placed on a filegroup or partition scheme. Remove the ON clause from the CREATE TABLE statement.

All memory optimized tables are mapped to memory-optimized filegroup.
Data typeData type nameThe indicated data type is not supported. Replace the type with one of the supported data types. For more information, see Supported Data Types for In-Memory OLTP.
FeatureComputed columnsComputed columns are not supported for memory-optimized tables. Remove the computed columns from the CREATE TABLE statement.
FeatureReplicationReplication is not supported with memory-optimized tables.
FeatureFILESTREAMFILESTREAM storage is not supported columns of memory-optimized tables. Remove the FILESTREAM keyword from the column definition.
FeatureSPARSEColumns of memory-optimized tables cannot be defined as SPARSE. Remove the SPARSE keyword from the column definition.
FeatureROWGUIDCOLThe option ROWGUIDCOL is not supported for columns of memory-optimized tables. Remove the ROWGUIDCOL keyword from the column definition.
FeatureFOREIGN KEYFor memory-optimized tables, FOREIGN KEY constraints are only supported for foreign keys referencing primary keys. Remove the constraint from the table definition if the foreign key references a unique constraint.
Featureclustered indexSpecify a nonclustered index. In the case of a primary key index be sure to specify PRIMARY KEY NONCLUSTERED [HASH].
FeatureDDL inside transactionsMemory-optimized tables and natively compiled stored procedures cannot be created or dropped in the context of a user transaction. Do not start a transaction and ensure the session setting IMPLICIT_TRANSACTIONS is OFF before executing the CREATE or DROP statement.
FeatureDDL triggersMemory-optimized tables and natively compiled stored procedures cannot be created or dropped if there is a server or database trigger for that DDL operation. Remove the server and database triggers on CREATE/DROP TABLE and CREATE/DROP PROCEDURE.
FeatureEVENT NOTIFICATIONMemory-optimized tables and natively compiled stored procedures cannot be created or dropped if there is a server or database event notification for that DDL operation. Remove the server and database event notifications on CREATE TABLE or DROP TABLE and CREATE PROCEDURE or DROP PROCEDURE.
FeatureFileTableMemory-optimized tables cannot be created as file tables. Remove the argument AS FileTable from the CREATE TABLE statement
OperationUpdate of primary key columnsPrimary key columns in memory-optimized tables and table types cannot be updated. If the primary key needs to be updated, delete the old row and insert the new row with the updated primary key.
OperationCREATE INDEXIndexes on memory-optimized tables must be specified inline with the CREATE TABLE statement, or with the ALTER TABLE statement.
OperationCREATE FULLTEXT INDEXFulltext indexes are not supported for memory-optimized tables.
Operationschema changeMemory-optimized tables and natively compiled stored procedures do not support schema changes, for example, sp_rename.

Attempting to make certain schema changes will generate error 12320. Operations that require a change to the schema version, for example renaming, are not supported with memory-optimized tables.

Certain schema changes using ALTER TABLE and ALTER PROCEDURE are allowed.
OperationTRUNCATE TABLEThe TRUNCATE operation is not supported for memory-optimized tables. To remove all rows from a table, delete all rows using DELETE FROMtable or drop and recreate the table.
OperationALTER AUTHORIZATIONChanging the owner of an existing memory-optimized table or natively compiled stored procedure is not supported. Drop and recreate the table or procedure to change ownership.
OperationALTER SCHEMATransferring a securable between schemas.
OperationDBCC CHECKTABLEDBCC CHECKTABLE is not supported with memory-optimized tables.
FeatureANSI_PADDING OFFThe session option ANSI_PADDING must be ON when creating memory-optimized tables or natively compiled stored procedures. Execute SET ANSI_PADDING ON before running the CREATE statement.
OptionDATA_COMPRESSIONData compression is not supported for memory-optimized tables. Remove the option from the table definition.
FeatureDTCMemory-optimized tables and natively compiled stored procedures cannot be accessed from distributed transactions. Use SQL transactions instead.
OperationMemory-optimized tables as target of MERGEMemory-optimized tables cannot be the target of a MERGE operation. Use INSERT, UPDATE, or DELETE statements instead.

The following table lists the Transact-SQL features and keywords that can appear in the message text of an error involving an index on a memory-optimized table, as well as the corrective action to resolve the error.

TypeNameResolution
FeatureFiltered indexFiltered indexes are not supported with memory-optimized tables. Omit the WHERE clause from the index specification.
FeatureIncluded columnsSpecifying included columns is not necessary for memory-optimized tables. All columns of the memory-optimized table are implicitly included in every memory-optimized index.
OperationDROP INDEXDropping indexes on memory-optimized tables is not supported. You can delete indexes using ALTER TABLE.

For more information, see Altering Memory-Optimized Tables.
Index optionIndex optionOnly one index option is supported – BUCKET_COUNT for HASH indexes.

The following table lists the Transact-SQL features and keywords that can appear in the message text of an error involving a nonclustered hash index, as well as the corrective action to resolve the error.

TypeNameResolution
OptionASC/DESCNonclustered hash indexes are not ordered. Remove the keywords ASC and DESC from the index key specification.

The following table lists the Transact-SQL features and keywords that can appear in the message text of an error involving natively compiled stored procedures and user-defined functions, as well as the corrective action to resolve the error.

TypeFeatureResolution
FeatureInline table variablesTable types cannot be declared inline with variable declarations. Table types must be declared explicitly using a CREATE TYPE statement.
FeatureCursorsCursors are not supported on or in natively compiled stored procedures.

When executing the procedure from the client, use RPC rather than the cursor API. With ODBC, avoid the Transact-SQL statement EXECUTE, instead specify the name of the procedure directly.

When executing the procedure from a Transact-SQL batch or another stored procedure, avoid using a cursor with the natively compiled stored procedure.

When creating a natively compiled stored procedure, rather than using a cursor, use set-based logic or a WHILE loop.
FeatureNon-constant parameter defaultsWhen using default values with parameters on natively compiled stored procedures, the values must be constants. Remove any wildcards from the parameter declarations.
FeatureEXTERNALCLR stored procedures cannot be natively compiled. Either remove the AS EXTERNAL clause or the NATIVE_COMPILATION option from the CREATE PROCEDURE statement.
FeatureNumbered stored proceduresNatively compiled stored procedures cannot be numbered. Remove the ;number from the CREATE PROCEDURE statement.
Featuremulti-row INSERT … VALUES statementsCannot insert multiple rows using the same INSERT statement in a natively compiled stored procedure. Create INSERT statements for each row.
FeatureCommon Table Expressions (CTEs)Common table expressions (CTE) are not supported in natively compiled stored procedures. Rewrite the query.
FeatureCOMPUTEThe COMPUTE clause is not supported. Remove it from the query.
FeatureSELECT INTOThe INTO clause is not supported with the SELECT statement. Rewrite the query as p INTOTableSELECT.
Featureincomplete insert column listIn general, in INSERT statements values must be specified for all columns in the table.

However, we do support DEFAULT constraints and IDENTITY(1,1) columns on memory optimized tables. These columns can be, and in the case of IDENTITY columns must be, omitted from the INSERT column list.
FeatureFunctionSome built-in functions are not supported in natively compiled stored procedures. Remove the rejected function from the stored procedure. For more information about supported built-in functions, see
Supported Features for Natively Compiled T-SQL Modules, or
Natively Compiled Stored Procedures.
FeatureCASEThe CASE statement is not supported in queries inside natively compiled stored procedures. Create queries for each case. For more information, see Implementing a CASE Expression in a Natively Compiled Stored Procedure.
FeatureINSERT EXECUTERemove the reference.
FeatureEXECUTESupported only to execute natively compiled stored procedures and user-defined functions.
Featureuser-defined aggregatesUser-defined aggregate functions cannot be used in natively compiled stored procedures. Remove the reference to the function from the procedure.
Featurebrowse mode metadataNatively compiled stored procedures do not support browse mode metadata. Make sure the session option NO_BROWSETABLE is set to OFF.
FeatureDELETE with FROM clauseThe FROM clause is not supported for DELETE statements with a table source in natively compiled stored procedures.

 DELETE with the FROM clause is supported when it is used to indicate the table to delete from.
FeatureUPDATE with FROM clauseThe FROM clause is not supported for UPDATE statements in natively compiled stored procedures.
Featuretemporary proceduresTemporary stored procedures cannot be natively compiled. Either create a permanent natively compiled stored procedure or a temporary interpreted Transact-SQL stored procedure.
Isolation levelREAD UNCOMMITTEDThe isolation level READ UNCOMMITTED is not supported for natively compiled stored procedures. Use a supported isolation level, such as SNAPSHOT.
Isolation levelREAD COMMITTEDThe isolation level READ COMMITTED is not supported for natively compiled stored procedures. Use a supported isolation level, such as SNAPSHOT.
Featuretemporary tablesTables in tempdb cannot be used in natively compiled stored procedures. Instead, use a table variable or a memory-optimized table with DURABILITY=SCHEMA_ONLY.
FeatureDTCMemory-optimized tables and natively compiled stored procedures cannot be accessed from distributed transactions. Use SQL transactions instead.
FeatureEXECUTE WITH RECOMPILEThe option WITH RECOMPILE is not supported for natively compiled stored procedures.
FeatureExecution from the dedicated administrator connection.Natively compiled stored procedures cannot be executed from the dedicated admin connection (DAC). Use a regular connection instead.
OperationsavepointNatively compiled stored procedures cannot be invoked from transactions that have an active savepoint. Remove the savepoint from the transaction.
OperationALTER AUTHORIZATIONChanging the owner of an existing memory-optimized table or natively compiled stored procedure is not supported. Drop and recreate the table or procedure to change ownership.
OperatorOPENROWSETThis operator is not supported. Remove OPENROWSET from the natively compiled stored procedure.
OperatorOPENQUERYThis operator is not supported. Remove OPENQUERY from the natively compiled stored procedure.
OperatorOPENDATASOURCEThis operator is not supported. Remove OPENDATASOURCE from the natively compiled stored procedure.
OperatorOPENXMLThis operator is not supported. Remove OPENXML from the natively compiled stored procedure.
OperatorCONTAINSTABLEThis operator is not supported. Remove CONTAINSTABLE from the natively compiled stored procedure.
OperatorFREETEXTTABLEThis operator is not supported. Remove FREETEXTTABLE from the natively compiled stored procedure.
Featuretable-valued functionsTable-valued functions cannot be referenced from natively compiled stored procedures. One possible workaround for this restriction is to add the logic in the table-valued functions to the procedure body.
OperatorCHANGETABLEThis operator is not supported. Remove CHANGETABLE from the natively compiled stored procedure.
OperatorGOTOThis operator is not supported. Use other procedural constructs such as WHILE.
OperatorOFFSETThis operator is not supported. Remove OFFSET from the natively compiled stored procedure.
OperatorINTERSECTThis operator is not supported. Remove INTERSECT from the natively compiled stored procedure. In some cases an INNER JOIN can be used to obtain the same result.
OperatorEXCEPTThis operator is not supported. Remove EXCEPT from the natively compiled stored procedure.
OperatorAPPLYThis operator is not supported. Remove APPLY from the natively compiled stored procedure.
OperatorPIVOTThis operator is not supported. Remove PIVOT from the natively compiled stored procedure.
OperatorUNPIVOTThis operator is not supported. Remove UNPIVOT from the natively compiled stored procedure.
OperatorCONTAINSThis operator is not supported. Remove CONTAINS from the natively compiled stored procedure.
OperatorFREETEXTThis operator is not supported. Remove FREETEXT from the natively compiled stored procedure.
OperatorTSEQUALThis operator is not supported. Remove TSEQUAL from the natively compiled stored procedure.
OperatorLIKEThis operator is not supported. Remove LIKE from the natively compiled stored procedure.
OperatorNEXT VALUE FORSequences cannot be referenced inside natively compiled stored procedures. Obtain the value using interpreted Transact-SQL, and then pass it into the natively compiled stored procedure. For more information, see Implementing IDENTITY in a Memory-Optimized Table.
Set optionoptionSET options cannot be changed inside natively compiled stored procedures. Certain options can be set with the BEGIN ATOMIC statement. For more information, see the section on atonic blocks in Natively Compiled Stored Procedures.
OperandTABLESAMPLEThis operator is not supported. Remove TABLESAMPLE from the natively compiled stored procedure.
OptionRECOMPILENatively compiled stored procedures are compiled at create time. Remove RECOMPILE from the procedure definition.

You can execute sp_recompile on a natively compiled stored procedure, which causes it to recompile on the next execution.
OptionENCRYPTIONThis option is not supported. Remove ENCRYPTION from the procedure definition.
OptionFOR REPLICATIONNatively compiled stored procedures cannot be created for replication. Removed FOR REPLICATION from the procedure definition.
OptionFOR XMLThis option is not supported. Remove FOR XML from the natively compiled stored procedure.
OptionFOR BROWSEThis option is not supported. Remove FOR BROWSE from the natively compiled stored procedure.
Join hintHASH, MERGENatively compiled stored procedures only support nested-loops joins. Hash and merge joins are not supported. Remove the join hint.
Query hintQuery hintThis query hint is not inside natively compiled stored procedures. For supported query hints see Query Hints (Transact-SQL).
OptionPERCENTThis option is not supported with TOP clauses. Remove PERCENT from the query in the natively compiled stored procedure.
OptionWITH TIESThis option is not supported with TOP clauses. Remove WITH TIES from the query in the natively compiled stored procedure.
Aggregate functionAggregate functionThis clause is not supported. For more information about aggregate functions in natively compiled stored procedures, see Natively Compiled Stored Procedures.
Ranking functionRanking functionRanking functions are not supported in natively compiled stored procedures. Remove them from the procedure definition.
FunctionFunctionThis function is not supported. Remove it from the natively compiled stored procedure.
StatementStatementThis statement is not supported. Remove it from the natively compiled stored procedure.
FeatureMIN and MAX used with binary and character stringsThe aggregate functions MIN and MAX cannot be used for character and binary string values inside natively compiled stored procedures.
FeatureGROUP BY ALLALL cannot be used with GROUP BY clauses in natively compiled stored procedures. Remove ALL from the GROUP BY clause.
FeatureGROUP BY ()Grouping by an empty list is not supported. Either remove the GROUP BY clause, or include columns in the grouping list.
FeatureROLLUPROLLUP cannot be used with GROUP BY clauses in natively compiled stored procedures. Remove ROLLUP from the procedure definition.
FeatureCUBECUBE cannot be used with GROUP BY clauses in natively compiled stored procedures. Remove CUBE from the procedure definition.
FeatureGROUPING SETSGROUPING SETS cannot be used with GROUP BY clauses in natively compiled stored procedures. Remove GROUPING SETS from the procedure definition.
FeatureBEGIN TRANSACTION, COMMIT TRANSACTION, and ROLLBACK TRANSACTIONUse ATOMIC blocks to control transactions and error handling. For more information, see Atomic Blocks.
FeatureInline table variable declarations.Table variables must reference explicitly defined memory-optimized table types. You should create a memory-optimized table type and use that type for the variable declaration, rather than specifying the type inline.
FeatureDisk-based tablesDisk-based tables cannot be accessed from natively compiled stored procedures. Remove references to disk-based tables from the natively-compiled stored procedures. Or, migrate the disk-based table(s) to memory optimized.
FeatureViewsViews cannot be accessed from natively compiled stored procedures. Instead of views, reference the underlying base tables.
FeatureTable valued functionsTable-valued functions cannot be accessed from natively compiled stored procedures. Remove references to table-valued functions from the natively compiled stored procedure.
OptionPRINTRemove reference
FeatureDDLNo DDL is supported.
OptionSTATISTICS XMLNot supported. When you run a query, with STATISTICS XML enabled, the XML content is returned without the part for the natively compiled stored procedure.

The following table lists the Transact-SQL features and keywords that can appear in the message text of an error involving transactions that access memory-optimized tables, as well as the corrective action to resolve the error.

TypeNameResolution
FeaturesavepointCreating explicit savepoints in transactions that access memory-optimized tables is not supported.
Featurebound transactionBound sessions cannot participate in transactions that access memory-optimized tables. Do not bind the session before executing the procedure.
FeatureDTCTransactions that access memory-optimized tables cannot be distributed transactions.

Migrating to In-Memory OLTP

Community Additions

ADD
Show:
© 2016 Microsoft