Demonstration: Performance Improvement of In-Memory OLTP
This example shows performance improvements when using In-Memory OLTP by comparing differences in response times when running an identical Transact-SQL query against memory-optimized and traditional disk-based tables. Additionally, a natively-compiled stored procedure is also created (based on the same query) and then run to demonstrate that you typically get the best response times when querying a memory-optimized table with a natively-compiled stored procedure. This sample only shows one aspect of performance improvements when accessing data in memory-optimized tables; data access efficiency when performing inserts. This sample is single-threaded and does not take advantage of the concurrency benefits of In-Memory OLTP. A workload that uses concurrency will see a greater performance gain.
Note
Another sample demonstrating memory-optimized tables is available at SQL Server 2014 In-Memory OLTP Sample.
To complete this sample you will perform the following:
Create a database named imoltp and alter its file details to set it up for using In-Memory OLTP.
Create the database objects for our sample: three tables and a natively-compiled stored procedure.
Run the different queries and display the response times for each query.
To setup the imoltp database for our example, first create an empty folder: c:\imoltp_data, and then run the following code:
USE master
GO
-- Create a new database.
CREATE DATABASE imoltp
GO
-- Prepare the database for In-Memory OLTP by
-- adding a memory-optimized filegroup to the database.
ALTER DATABASE imoltp ADD FILEGROUP imoltp_file_group
CONTAINS MEMORY_OPTIMIZED_DATA;
-- Add a file (to hold the memory-optimized data) to the new filegroup.
ALTER DATABASE imoltp ADD FILE (name='imoltp_file', filename='c:\imoltp_data\imoltp_file')
TO FILEGROUP imoltp_file_group;
GO
Next, run the following code to create the disk-based table, two (2) memory-optimized tables, and the natively-compiled stored procedure that will be used to demonstrate the different data access methods:
USE imoltp
GO
-- If the tables or stored procedure already exist, drop them to start clean.
IF EXISTS (SELECT NAME FROM sys.objects WHERE NAME = 'DiskBasedTable')
DROP TABLE [dbo].[DiskBasedTable]
GO
IF EXISTS (SELECT NAME FROM sys.objects WHERE NAME = 'InMemTable')
DROP TABLE [dbo].[InMemTable]
GO
IF EXISTS (SELECT NAME FROM sys.objects WHERE NAME = 'InMemTable2')
DROP TABLE [dbo].[InMemTable2]
GO
IF EXISTS (SELECT NAME FROM sys.objects WHERE NAME = 'usp_InsertData')
DROP PROCEDURE [dbo].[usp_InsertData]
GO
-- Create a traditional disk-based table.
CREATE TABLE [dbo].[DiskBasedTable] (
c1 INT NOT NULL PRIMARY KEY,
c2 NCHAR(48) NOT NULL
)
GO
-- Create a memory-optimized table.
CREATE TABLE [dbo].[InMemTable] (
c1 INT NOT NULL PRIMARY KEY NONCLUSTERED HASH WITH (BUCKET_COUNT=1000000),
c2 NCHAR(48) NOT NULL
) WITH (MEMORY_OPTIMIZED=ON, DURABILITY = SCHEMA_AND_DATA);
GO
-- Create a 2nd memory-optimized table.
CREATE TABLE [dbo].[InMemTable2] (
c1 INT NOT NULL PRIMARY KEY NONCLUSTERED HASH WITH (BUCKET_COUNT=1000000),
c2 NCHAR(48) NOT NULL
) WITH (MEMORY_OPTIMIZED=ON, DURABILITY = SCHEMA_AND_DATA);
GO
-- Create a natively-compiled stored procedure.
CREATE PROCEDURE [dbo].[usp_InsertData]
@rowcount INT,
@c NCHAR(48)
WITH NATIVE_COMPILATION, SCHEMABINDING, EXECUTE AS OWNER
AS
BEGIN ATOMIC
WITH (TRANSACTION ISOLATION LEVEL = SNAPSHOT, LANGUAGE = N'us_english')
DECLARE @i INT = 1;
WHILE @i <= @rowcount
BEGIN
INSERT INTO [dbo].[inMemTable2](c1,c2) VALUES (@i, @c);
SET @i += 1;
END
END
GO
The setup is complete and we are ready to execute the queries that will display the response times comparing the performance between the data access methods.
To complete the example run the following code multiple times. Ignore the results from the first run which is negatively affected by initial memory allocation.
SET STATISTICS TIME OFF;
SET NOCOUNT ON;
-- Delete data from all tables to reset the example.
DELETE FROM [dbo].[DiskBasedTable]
WHERE [c1]>0
GO
DELETE FROM [dbo].[inMemTable]
WHERE [c1]>0
GO
DELETE FROM [dbo].[InMemTable2]
WHERE [c1]>0
GO
-- Declare parameters for the test queries.
DECLARE @i INT = 1;
DECLARE @rowcount INT = 100000;
DECLARE @c NCHAR(48) = N'12345678901234567890123456789012345678';
DECLARE @timems INT;
DECLARE @starttime datetime2 = sysdatetime();
-- Disk-based table queried with interpreted Transact-SQL.
BEGIN TRAN
WHILE @I <= @rowcount
BEGIN
INSERT INTO [dbo].[DiskBasedTable](c1,c2) VALUES (@i, @c);
SET @i += 1;
END
COMMIT
SET @timems = datediff(ms, @starttime, sysdatetime());
SELECT CAST(@timems AS VARCHAR(10)) + ' ms (disk-based table with interpreted Transact-SQL).';
-- Memory-optimized table queried with interpreted Transact-SQL.
SET @i = 1;
SET @starttime = sysdatetime();
BEGIN TRAN
WHILE @i <= @rowcount
BEGIN
INSERT INTO [dbo].[InMemTable](c1,c2) VALUES (@i, @c);
SET @i += 1;
END
COMMIT
SET @timems = datediff(ms, @starttime, sysdatetime());
SELECT CAST(@timems AS VARCHAR(10)) + ' ms (memory-optimized table with interpreted Transact-SQL).';
-- Memory-optimized table queried with a natively-compiled stored procedure.
SET @starttime = sysdatetime();
EXEC usp_InsertData @rowcount, @c;
SET @timems = datediff(ms, @starttime, sysdatetime());
SELECT CAST(@timems AS VARCHAR(10)) + ' ms (memory-optimized table with natively-compiled stored procedure).';
The expected results provide actual response times showing how using memory-optimized tables and natively-compiled stored procedures typically provides consistently faster response times than the same workloads running against traditional disk-based tables.
See Also
Extensions to AdventureWorks to Demonstrate In-Memory OLTP
In-Memory OLTP (In-Memory Optimization)
Memory-Optimized Tables
Natively Compiled Stored Procedures
Requirements for Using Memory-Optimized Tables
CREATE DATABASE (SQL Server Transact-SQL)
ALTER DATABASE File and Filegroup Options (Transact-SQL)
CREATE PROCEDURE and Memory-Optimized Tables