|
| 1 | +-- https://docs.microsoft.com/en-us/sql/relational-databases/in-memory-oltp/overview-and-usage-scenarios |
| 2 | +USE master; |
| 3 | + |
| 4 | +CREATE DATABASE [TESTDB] |
| 5 | + CONTAINMENT = NONE |
| 6 | + ON PRIMARY |
| 7 | +( NAME = N'TESTDB', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\TESTDB.mdf', SIZE = 64MB, MAXSIZE = UNLIMITED, FILEGROWTH = 64MB), |
| 8 | +FILEGROUP [TESTDB] CONTAINS MEMORY_OPTIMIZED_DATA DEFAULT |
| 9 | +( NAME = N'TESTDB_mod', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\TESTDB_mod', MAXSIZE = UNLIMITED) |
| 10 | + LOG ON |
| 11 | +( NAME = N'TESTDB_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\TESTDB_log.ldf', SIZE = 64MB, MAXSIZE = 2048MB, FILEGROWTH = 64MB) |
| 12 | +GO |
| 13 | + |
| 14 | +USE [TESTDB] |
| 15 | +GO |
| 16 | + |
| 17 | +-- configure recommended DB option |
| 18 | + ALTER DATABASE CURRENT SET MEMORY_OPTIMIZED_ELEVATE_TO_SNAPSHOT=ON |
| 19 | + GO |
| 20 | + -- memory-optimized table |
| 21 | + CREATE TABLE dbo.table1 |
| 22 | + ( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED, |
| 23 | + c2 NVARCHAR(MAX)) |
| 24 | + WITH (MEMORY_OPTIMIZED=ON) |
| 25 | + GO |
| 26 | + -- non-durable table |
| 27 | + CREATE TABLE dbo.temp_table1 |
| 28 | + ( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED, |
| 29 | + c2 NVARCHAR(MAX)) |
| 30 | + WITH (MEMORY_OPTIMIZED=ON, |
| 31 | + DURABILITY=SCHEMA_ONLY) |
| 32 | + GO |
| 33 | + -- memory-optimized table type |
| 34 | + CREATE TYPE dbo.tt_table1 AS TABLE |
| 35 | + ( c1 INT IDENTITY, |
| 36 | + c2 NVARCHAR(MAX), |
| 37 | + is_transient BIT NOT NULL DEFAULT (0), |
| 38 | + INDEX ix_c1 HASH (c1) WITH (BUCKET_COUNT=1024)) |
| 39 | + WITH (MEMORY_OPTIMIZED=ON) |
| 40 | + GO |
| 41 | + -- natively compiled stored procedure |
| 42 | + CREATE PROCEDURE dbo.usp_ingest_table1 |
| 43 | + @table1 dbo.tt_table1 READONLY |
| 44 | + WITH NATIVE_COMPILATION, SCHEMABINDING |
| 45 | + AS |
| 46 | + BEGIN ATOMIC |
| 47 | + WITH (TRANSACTION ISOLATION LEVEL=SNAPSHOT, |
| 48 | + LANGUAGE=N'us_english') |
| 49 | + |
| 50 | + DECLARE @i INT = 1 |
| 51 | + |
| 52 | + WHILE @i > 0 |
| 53 | + BEGIN |
| 54 | + INSERT dbo.table1 |
| 55 | + SELECT c2 |
| 56 | + FROM @table1 |
| 57 | + WHERE c1 = @i AND is_transient=0 |
| 58 | + |
| 59 | + IF @@ROWCOUNT > 0 |
| 60 | + SET @i += 1 |
| 61 | + ELSE |
| 62 | + BEGIN |
| 63 | + INSERT dbo.temp_table1 |
| 64 | + SELECT c2 |
| 65 | + FROM @table1 |
| 66 | + WHERE c1 = @i AND is_transient=1 |
| 67 | + |
| 68 | + IF @@ROWCOUNT > 0 |
| 69 | + SET @i += 1 |
| 70 | + ELSE |
| 71 | + SET @i = 0 |
| 72 | + END |
| 73 | + END |
| 74 | + |
| 75 | + END |
| 76 | + GO |
| 77 | + -- sample execution of the proc |
| 78 | +DECLARE @table1 dbo.tt_table1 |
| 79 | +INSERT @table1 (c2, is_transient) VALUES (N'sample durable', 0) |
| 80 | +INSERT @table1 (c2, is_transient) VALUES (N'sample non-durable', 1) |
| 81 | +EXECUTE dbo.usp_ingest_table1 @table1=@table1 |
| 82 | +SELECT c1, c2 from dbo.table1 |
| 83 | +SELECT c1, c2 from dbo.temp_table1 |
| 84 | +GO |
0 commit comments