Skip to content

Commit e38d015

Browse files
committed
Completely improve In-Memory test scripts for full dynamic sql support
1 parent 0bd4589 commit e38d015

File tree

2 files changed

+157
-94
lines changed

2 files changed

+157
-94
lines changed

Scripts/IN_Memory_Example_2014.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,7 @@
22
USE master;
33
GO
44

5-
DECLARE @databaseFilePath NVARCHAR(1000) = N'k:\MSSQL\MSSQL14.MSSQLSERVER\MSSQL\DATA\'--N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\';
5+
DECLARE @databaseFilePath NVARCHAR(1000) = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\';
66
DECLARE @databaseName SYSNAME = N'ಠ ಠ 14 Test';
77
DECLARE @tsqlStatement NVARCHAR(4000) = N'';
88
DECLARE @debug BIT = 0;
@@ -18,7 +18,7 @@ CREATE DATABASE [@databaseName]
1818
CONTAINMENT = NONE
1919
ON PRIMARY
2020
(NAME = N''@databaseName'', FILENAME = N''@databaseFilePath@databaseName.mdf'', SIZE = 64MB, MAXSIZE = UNLIMITED, FILEGROWTH = 64MB),
21-
FILEGROUP [___DATABASE_NAME___] CONTAINS MEMORY_OPTIMIZED_DATA DEFAULT
21+
FILEGROUP [@databaseName] CONTAINS MEMORY_OPTIMIZED_DATA DEFAULT
2222
( NAME = N''@databaseName_mod'', FILENAME = N''@databaseFilePath@databaseName_mod'', MAXSIZE = UNLIMITED)
2323
LOG ON
2424
( NAME = N''@databaseName_log'', FILENAME = N''@databaseFilePath@databaseName_log.ldf'', SIZE = 64MB, MAXSIZE = 2048MB, FILEGROWTH = 64MB);

Scripts/IN_Memory_Example_2017.sql

Lines changed: 155 additions & 92 deletions
Original file line numberDiff line numberDiff line change
@@ -1,117 +1,180 @@
11
-- https://docs.microsoft.com/en-us/sql/relational-databases/in-memory-oltp/overview-and-usage-scenarios
22
USE master;
3+
GO
4+
5+
6+
DECLARE @databaseFilePath NVARCHAR(1000) = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\';
7+
DECLARE @databaseName SYSNAME = N'ಠ ಠ 17 Test';
8+
DECLARE @tsqlStatement NVARCHAR(4000) = N'';
9+
DECLARE @debug BIT = 0;
310

4-
IF DB_ID(N'ಠ ಠ 17 Test') IS NOT NULL DROP DATABASE [ಠ ಠ 17 Test];
11+
SET @tsqlStatement = '
12+
IF DB_ID(N''@databaseName'') IS NOT NULL
13+
BEGIN
14+
ALTER DATABASE [@databaseName] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
15+
DROP DATABASE [@databaseName];
16+
END;
517
6-
CREATE DATABASE [ಠ ಠ 17 Test]
18+
CREATE DATABASE [@databaseName]
719
CONTAINMENT = NONE
8-
ON PRIMARY
9-
( NAME = N'ಠ ಠ 17 Test', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\ಠ ಠ 17 Test.mdf', SIZE = 64MB, MAXSIZE = UNLIMITED, FILEGROWTH = 64MB),
10-
FILEGROUP [ಠ ಠ 17 Test] CONTAINS MEMORY_OPTIMIZED_DATA DEFAULT
11-
( NAME = N'TESTDB_mod', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\ಠ ಠ 17 Test_mod', MAXSIZE = UNLIMITED)
12-
LOG ON
13-
( NAME = N'TESTDB_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL14.MSSQLSERVER\MSSQL\DATA\ಠ ಠ 17 Test_log.ldf', SIZE = 64MB, MAXSIZE = 2048MB, FILEGROWTH = 64MB)
14-
GO
20+
ON PRIMARY
21+
(NAME = N''@databaseName'', FILENAME = N''@databaseFilePath@databaseName.mdf'', SIZE = 64MB, MAXSIZE = UNLIMITED, FILEGROWTH = 64MB),
22+
FILEGROUP [@databaseName] CONTAINS MEMORY_OPTIMIZED_DATA DEFAULT
23+
( NAME = N''@databaseName_mod'', FILENAME = N''@databaseFilePath@databaseName_mod'', MAXSIZE = UNLIMITED)
24+
LOG ON
25+
( NAME = N''@databaseName_log'', FILENAME = N''@databaseFilePath@databaseName_log.ldf'', SIZE = 64MB, MAXSIZE = 2048MB, FILEGROWTH = 64MB);
1526
16-
USE [ಠ ಠ 17 Test];
17-
GO
27+
ALTER DATABASE [@databaseName] SET COMPATIBILITY_LEVEL = 140;
28+
';
29+
30+
SET @tsqlStatement = REPLACE(@tsqlStatement, '@databaseName', @databaseName);
31+
SET @tsqlStatement = REPLACE(@tsqlStatement, '@databaseFilePath', @databaseFilePath);
32+
33+
IF @debug = 1 PRINT(@tsqlStatement)
34+
ELSE
35+
EXEC sp_executesql @tsqlStatement;
36+
37+
38+
SET @tsqlStatement = '
39+
USE [@databaseName];
40+
--UNCOMMENT GO Statement if you want to execute statements after printing in debug mode!!!
41+
--GO
1842
1943
-- configure recommended DB option
20-
ALTER DATABASE CURRENT SET MEMORY_OPTIMIZED_ELEVATE_TO_SNAPSHOT=ON;
21-
GO
22-
-- memory-optimized table
23-
CREATE TABLE dbo.table1
24-
( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED,
25-
c2 NVARCHAR(MAX))
26-
WITH (MEMORY_OPTIMIZED=ON)
27-
GO
28-
-- non-durable table
29-
CREATE TABLE dbo.temp_table1
30-
( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED,
31-
c2 NVARCHAR(MAX))
32-
WITH (MEMORY_OPTIMIZED=ON,
33-
DURABILITY=SCHEMA_ONLY)
34-
GO
35-
-- memory-optimized table type
36-
CREATE TYPE dbo.tt_table1 AS TABLE
37-
( c1 INT IDENTITY,
38-
c2 NVARCHAR(MAX),
39-
is_transient BIT NOT NULL DEFAULT (0),
40-
INDEX ix_c1 HASH (c1) WITH (BUCKET_COUNT=1024))
41-
WITH (MEMORY_OPTIMIZED=ON)
42-
GO
43-
-- natively compiled stored procedure
44-
CREATE PROCEDURE dbo.usp_ingest_table1
45-
@table1 dbo.tt_table1 READONLY
46-
WITH NATIVE_COMPILATION, SCHEMABINDING
47-
AS
48-
BEGIN ATOMIC
49-
WITH (TRANSACTION ISOLATION LEVEL=SNAPSHOT,
50-
LANGUAGE=N'us_english')
51-
52-
DECLARE @i INT = 1
53-
54-
WHILE @i > 0
55-
BEGIN
56-
INSERT dbo.table1
57-
SELECT c2
58-
FROM @table1
59-
WHERE c1 = @i AND is_transient=0
60-
61-
IF @@ROWCOUNT > 0
62-
SET @i += 1
63-
ELSE
64-
BEGIN
65-
INSERT dbo.temp_table1
66-
SELECT c2
67-
FROM @table1
68-
WHERE c1 = @i AND is_transient=1
69-
70-
IF @@ROWCOUNT > 0
71-
SET @i += 1
72-
ELSE
73-
SET @i = 0
74-
END
75-
END
76-
77-
END
78-
GO
79-
-- sample execution of the proc
80-
DECLARE @table1 dbo.tt_table1
81-
INSERT @table1 (c2, is_transient) VALUES (N'sample durable', 0)
82-
INSERT @table1 (c2, is_transient) VALUES (N'sample non-durable', 1)
83-
EXECUTE dbo.usp_ingest_table1 @table1=@table1
84-
SELECT c1, c2 from dbo.table1
85-
SELECT c1, c2 from dbo.temp_table1
86-
GO
44+
ALTER DATABASE CURRENT SET MEMORY_OPTIMIZED_ELEVATE_TO_SNAPSHOT=ON;
8745
88-
CREATE TABLE dbo.InMemTable1
89-
(
90-
keyColumn INT IDENTITY PRIMARY KEY NONCLUSTERED
91-
,description CHAR(100) NOT NULL
46+
-- memory-optimized table
47+
CREATE TABLE dbo.table1
48+
( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED,
49+
c2 NVARCHAR(MAX))
50+
WITH (MEMORY_OPTIMIZED=ON);
51+
52+
-- non-durable table
53+
CREATE TABLE dbo.temp_table1
54+
( c1 INT IDENTITY PRIMARY KEY NONCLUSTERED,
55+
c2 NVARCHAR(MAX))
56+
WITH (MEMORY_OPTIMIZED=ON,
57+
DURABILITY=SCHEMA_ONLY);
58+
59+
-- memory-optimized table type
60+
CREATE TYPE dbo.tt_table1 AS TABLE
61+
( c1 INT IDENTITY,
62+
c2 NVARCHAR(MAX),
63+
is_transient BIT NOT NULL DEFAULT (0),
64+
INDEX ix_c1 HASH (c1) WITH (BUCKET_COUNT=1024))
65+
WITH (MEMORY_OPTIMIZED=ON);
66+
67+
CREATE TABLE dbo.InMemTable1(
68+
keyColumn INT IDENTITY PRIMARY KEY NONCLUSTERED
69+
, description CHAR(100) NOT NULL
9270
)
93-
WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA)
71+
WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA);
9472
9573
INSERT dbo.InMemTable1
9674
(
9775
description
9876
)
9977
VALUES
100-
(REPLICATE('A', 100))
101-
,(REPLICATE('B', 100))
102-
,(REPLICATE('C', 100))
103-
,(REPLICATE('D', 100))
104-
,(REPLICATE('E', 100))
105-
,(REPLICATE('F', 100))
106-
GO
78+
(REPLICATE(''A'', 100))
79+
,(REPLICATE(''B'', 100))
80+
,(REPLICATE(''C'', 100))
81+
,(REPLICATE(''D'', 100))
82+
,(REPLICATE(''E'', 100))
83+
,(REPLICATE(''F'', 100));
84+
';
85+
86+
SET @tsqlStatement = REPLACE(@tsqlStatement, '@databaseName', @databaseName);
87+
88+
IF @debug = 1 PRINT(@tsqlStatement)
89+
ELSE
90+
EXEC sp_executesql @tsqlStatement;
91+
10792

93+
-- https://stackoverflow.com/a/793362/2298061
94+
DECLARE @UseAndExecStatment NVARCHAR(4000);
95+
SET @UseAndExecStatment = N'USE [' + @databaseName + N']; EXEC sp_executesql @tsqlStatement';
96+
97+
SET @tsqlStatement = N'
98+
-- natively compiled stored procedure
99+
CREATE PROCEDURE dbo.usp_ingest_table1
100+
@table1 dbo.tt_table1 READONLY
101+
WITH NATIVE_COMPILATION, SCHEMABINDING
102+
AS
103+
BEGIN ATOMIC
104+
WITH (TRANSACTION ISOLATION LEVEL=SNAPSHOT,
105+
LANGUAGE=N''us_english'')
106+
107+
DECLARE @i INT = 1
108+
109+
WHILE @i > 0
110+
BEGIN
111+
INSERT dbo.table1
112+
SELECT c2
113+
FROM @table1
114+
WHERE c1 = @i AND is_transient=0
115+
116+
IF @@ROWCOUNT > 0
117+
SET @i += 1
118+
ELSE
119+
BEGIN
120+
INSERT dbo.temp_table1
121+
SELECT c2
122+
FROM @table1
123+
WHERE c1 = @i AND is_transient=1
124+
125+
IF @@ROWCOUNT > 0
126+
SET @i += 1
127+
ELSE
128+
SET @i = 0
129+
END
130+
END
131+
END;';
132+
133+
IF @debug = 1 PRINT(@tsqlStatement)
134+
ELSE
135+
BEGIN
136+
EXEC sp_executesql @UseAndExecStatment,
137+
N'@tsqlStatement NVARCHAR(MAX)', @tsqlStatement = @tsqlStatement;
138+
END;
139+
140+
141+
SET @UseAndExecStatment = N'USE [' + @databaseName + N']; EXEC sp_executesql @tsqlStatement';
142+
SET @tsqlStatement = N'
108143
CREATE OR ALTER PROCEDURE dbo.native_sp
109144
WITH NATIVE_COMPILATION, SCHEMABINDING, EXECUTE AS OWNER
110145
AS
111-
BEGIN ATOMIC WITH (TRANSACTION ISOLATION LEVEL = SNAPSHOT, LANGUAGE = N'us_english')
146+
BEGIN ATOMIC WITH (TRANSACTION ISOLATION LEVEL = SNAPSHOT, LANGUAGE = N''us_english'')
112147
SELECT keyColumn
113148
,description
114149
FROM dbo.InMemTable1;
150+
END;';
151+
152+
IF @debug = 1 PRINT(@tsqlStatement)
153+
ELSE
154+
BEGIN
155+
EXEC sp_executesql @UseAndExecStatment,
156+
N'@tsqlStatement NVARCHAR(MAX)', @tsqlStatement = @tsqlStatement;
115157
END;
116-
GO
158+
159+
160+
SET @UseAndExecStatment = N'USE [' + @databaseName + N']; EXEC sp_executesql @tsqlStatement';
161+
SET @tsqlStatement = '
162+
-- sample execution of the proc
163+
DECLARE @table1 dbo.tt_table1;
164+
INSERT @table1 (c2, is_transient) VALUES (N''sample durable'', 0);
165+
INSERT @table1 (c2, is_transient) VALUES (N''sample non-durable'', 1);
166+
167+
EXECUTE dbo.usp_ingest_table1 @table1=@table1
168+
169+
SELECT c1, c2 from dbo.table1
170+
SELECT c1, c2 from dbo.temp_table1;
171+
117172
EXECUTE dbo.native_sp;
173+
';
174+
175+
IF @debug = 1 PRINT(@tsqlStatement)
176+
ELSE
177+
BEGIN
178+
EXEC sp_executesql @UseAndExecStatment,
179+
N'@tsqlStatement NVARCHAR(MAX)', @tsqlStatement = @tsqlStatement;
180+
END;

0 commit comments

Comments
 (0)