Pastebin
API
tools
faq
paste
Login
Sign up
Please fix the following errors:
New Paste
Syntax Highlighting
/**************************************************************************************************************** This SQL pertains to the following DBA.StackExchange answer: http://dba.stackexchange.com/questions/136674/lob-data-slow-table-scans-and-some-i-o-questions/137869#137869 By: Solomon Rutzky Created on: 2016-05-09 Last Modified on: 2016-05-11 URL of this script: http://pastebin.com/bsrPj2u7 ****************************************************************************************************************/ ----------------------------------------------------------------------------- ----------------------------------------------------------------------------- ---- ---- Do not run this script all at once! ---- Run the block-comment sections as each one indicates. ---- Highlight and execute each numbered section independently, and in order. ---- ----------------------------------------------------------------------------- ----------------------------------------------------------------------------- /* -- Highlight and execute the following statements once: USE [tempdb]; SET ANSI_NULLS, QUOTED_IDENTIFIER, NOCOUNT ON; GO -- DROP TABLE #XmlTest; CREATE TABLE #XmlTest (Col1 INT PRIMARY KEY CLUSTERED, Col2 BIGINT, Col3 DATETIME, Col4 UNIQUEIDENTIFIER, Col5 XML); */ -- 1A) IN_ROW LOB data INSERT INTO #XmlTest (Col1, Col2, Col3, Col4, Col5) VALUES (1, 200000000, GETDATE(), NEWID(), N'<test name="in row LOB"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'a'), 3960) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest tmp WHERE tmp.Col1 = 1; -- 7999 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest'), NULL, NULL, N'DETAILED'); -- 1 page of IN_ROW_DATA : IAM_PAGE -- 1 page of IN_ROW_DATA : DATA_PAGE -- 1B) Inline Root LOB data INSERT INTO #XmlTest (Col1, Col2, Col3, Col4, Col5) VALUES (2, 400000000, GETDATE(), NEWID(), N'<test name="inline root LOB"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'b'), 20055) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest tmp WHERE tmp.Col1 = 2; -- 40200 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 1 pre-existing page of IN_ROW_DATA : DATA_PAGE -- 1 new page of IN_ROW_DATA : INDEX_PAGE -- 1 new page of IN_ROW_DATA : DATA_PAGE -- 1 new page of LOB_DATA : IAM_PAGE -- 6 new pages of LOB_DATA : TEXT_MIX_PAGE (1 TEXT_MIX_PAGE allocated and in LOB IAM page, but not in DATA_PAGE Inline Root) -- 1C) TEXT_TREE LOB data INSERT INTO #XmlTest (Col1, Col2, Col3, Col4, Col5) VALUES (3, 600000000, GETDATE(), NEWID(), N'<test name="text_tree LOB"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'c'), 20058) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest tmp WHERE tmp.Col1 = 3; -- 40202 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 1 pre-existing page of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page of IN_ROW_DATA : INDEX_PAGE -- 1 pre-existing page of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page of LOB_DATA : IAM_PAGE -- 6 pre-existing pages of LOB_DATA : TEXT_MIX_PAGE (1 TEXT_MIX_PAGE allocated and in LOB IAM page, but not in DATA_PAGE Inline Root) -- 5 new pages of LOB_DATA : TEXT_MIX_PAGE -- 1 new page of LOB_DATA : TEXT_TREE_PAGE -- Capture PageIDs so we can check against Buffer Pool without reading them into the Buffer Pool /* -- Highlight and execute the statements below once: -- DROP TABLE #Pages; CREATE TABLE #Pages (FileID INT, PageID INT); INSERT INTO #Pages (FileID, PageID) SELECT dddpa.allocated_page_file_id, dddpa.allocated_page_page_id FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest'), NULL, NULL, N'DETAILED') dddpa; SELECT * FROM #Pages; */ USE [tempdb]; /* -- Before each test, highlight and execute the 3 lines below: CHECKPOINT; DBCC DROPCLEANBUFFERS; SELECT * FROM sys.dm_os_buffer_descriptors dobd WHERE dobd.database_id = DB_ID(N'tempdb'); */ -- 1D) Check "all columns" reads for IN_ROW LOB data SET STATISTICS IO ON; SELECT * FROM #XmlTest WHERE Col1 = 1; SET STATISTICS IO OFF; -- Table '#XmlTest'. Scan count 0, logical reads 2, physical reads 2, read-ahead reads 0, -- lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. /* -- After each test, highlight and execute the following query: SELECT * FROM sys.dm_os_buffer_descriptors dobd INNER JOIN #Pages tmp ON tmp.FileID = dobd.[file_id] AND tmp.PageID = dobd.page_id WHERE dobd.database_id = DB_ID(N'tempdb'); */ -- 1E) Check "all columns" reads for Inline Root LOB data (off row) SET STATISTICS IO ON; SELECT * FROM #XmlTest WHERE Col1 = 2; SET STATISTICS IO OFF; -- Table '#XmlTest'. Scan count 0, logical reads 2, physical reads 2, read-ahead reads 0, -- lob logical reads 14, lob physical reads 0, lob read-ahead reads 16. -- 1F) Check "all columns" reads for TEXT_TREE LOB data (off row) SET STATISTICS IO ON; SELECT * FROM #XmlTest WHERE Col1 = 3; SET STATISTICS IO OFF; -- Table '#XmlTest'. Scan count 0, logical reads 2, physical reads 2, read-ahead reads 0, -- lob logical reads 30, lob physical reads 1, lob read-ahead reads 15. /* -- Before each test, highlight and execute the 3 lines below: CHECKPOINT; DBCC DROPCLEANBUFFERS; SELECT * FROM sys.dm_os_buffer_descriptors dobd WHERE dobd.database_id = DB_ID(N'tempdb'); */ -- 1G) Check non-XML columns reads for row with Inline Root LOB data (off row) SET STATISTICS IO ON; SELECT tmp.Col1, tmp.Col2, tmp.Col3, tmp.Col4 FROM #XmlTest tmp WHERE Col1 = 2; SET STATISTICS IO OFF; -- Table '#XmlTest'. Scan count 0, logical reads 2, physical reads 2, read-ahead reads 0, -- lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. -- 1H) Check non-XML columns reads for TEXT_TREE LOB data (off row) SET STATISTICS IO ON; SELECT tmp.Col1, tmp.Col2, tmp.Col3, tmp.Col4 FROM #XmlTest tmp WHERE Col1 = 3; SET STATISTICS IO OFF; -- Table '#XmlTest'. Scan count 0, logical reads 2, physical reads 2, read-ahead reads 0, -- lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. ----------------------------------------------------------------------------------- ----------------------------------------------------------------------------------- -- -- PART 2: Test effect of not having enough space left in-row for all 5 pointers -- of the Inline Root. Will the Inline Root be skipped and go directly -- to using a TEXT_TREE, or will it use as many pointers as will fit? -- ----------------------------------------------------------------------------------- /* -- Highlight and execute the following statements once: USE [tempdb]; SET ANSI_NULLS, QUOTED_IDENTIFIER, NOCOUNT ON; GO -- DROP TABLE #XmlTest2; CREATE TABLE #XmlTest2 (Col1 INT PRIMARY KEY CLUSTERED, Col2 INT, Col3 SMALLDATETIME, Col4 CHAR(7980), Col5 XML); */ -- 2A) IN_ROW LOB data INSERT INTO #XmlTest2 (Col1, Col2, Col3, Col4, Col5) VALUES (1, 20, GETDATE(), REPLICATE('Z', 7980), N'<test name="in-row"/>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest2 tmp WHERE tmp.Col1 = 1; -- 53 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest2'), NULL, NULL, N'DETAILED'); -- 1 page of IN_ROW_DATA : IAM_PAGE -- 1 page of IN_ROW_DATA : DATA_PAGE ---- 2 pages total -- 2B) Inline Root LOB data # 1 (small, but cannot fit in-row) INSERT INTO #XmlTest2 (Col1, Col2, Col3, Col4, Col5) VALUES (2, 40, GETDATE(), REPLICATE('Y', 7980), N'<test name="inline root LOB # 1"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'a'), 3) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest2 tmp WHERE tmp.Col1 = 2; -- 102 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest2'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 1 pre-existing page of IN_ROW_DATA : DATA_PAGE -- 1 new page of IN_ROW_DATA : INDEX_PAGE -- 1 new page of IN_ROW_DATA : DATA_PAGE -- 1 new page of LOB_DATA : IAM_PAGE -- 1 new page of LOB_DATA : TEXT_MIX_PAGE (50% free space) ---- 6 pages total -- 2C) Inline Root LOB data # 2 (should require 2 LOB pages = 36 bytes for in-row pointers) INSERT INTO #XmlTest2 (Col1, Col2, Col3, Col4, Col5) VALUES (3, 60, GETDATE(), REPLICATE('X', 7980), N'<test name="inline root LOB # 2"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'b'), 4500) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest2 tmp WHERE tmp.Col1 = 3; -- 9097 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest2'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 2 pre-existing pages of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page page of IN_ROW_DATA : INDEX_PAGE -- 1 new page of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page of LOB_DATA : IAM_PAGE -- 1 pre-existing page of LOB_DATA : TEXT_MIX_PAGE (50% free space) -- 1 new page of LOB_DATA : TEXT_MIX_PAGE (0% free space) ---- 8 pages total -- 2D) Inline Root LOB data # 3 (should require 3 LOB pages = 48 bytes for in-row pointers) INSERT INTO #XmlTest2 (Col1, Col2, Col3, Col4, Col5) VALUES (4, 80, GETDATE(), REPLICATE('W', 7980), N'<test name="inline root LOB # 3"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'c'), 12011) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest2 tmp WHERE tmp.Col1 = 4; -- 24119 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest2'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 3 pre-existing pages of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page page of IN_ROW_DATA : INDEX_PAGE -- 1 new page of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page of LOB_DATA : IAM_PAGE -- 1 pre-existing page of LOB_DATA : TEXT_MIX_PAGE (50% free space) -- 1 pre-existing page of LOB_DATA : TEXT_MIX_PAGE (0% free space) -- 3 new page of LOB_DATA : TEXT_MIX_PAGE (0% free space) ---- 12 pages total -- 2E) TEXT_TREE LOB data (should require 4 LOB pages = 60 bytes for in-row pointers, BUT not enough space left for 60 bytes) INSERT INTO #XmlTest2 (Col1, Col2, Col3, Col4, Col5) VALUES (5, 100, GETDATE(), REPLICATE('V', 7980), N'<test name="text_tree LOB"><val>' + REPLICATE(CONVERT(NVARCHAR(MAX), N'd'), 12018) + N'</val></test>'); SELECT DATALENGTH(tmp.Col5) FROM #XmlTest2 tmp WHERE tmp.Col1 = 5; -- 24121 bytes SELECT * FROM sys.dm_db_database_page_allocations(DB_ID(N'tempdb'), OBJECT_ID(N'tempdb..#XmlTest2'), NULL, NULL, N'DETAILED'); -- 1 pre-existing page of IN_ROW_DATA : IAM_PAGE -- 4 pre-existing pages of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page page of IN_ROW_DATA : INDEX_PAGE -- 1 new page of IN_ROW_DATA : DATA_PAGE -- 1 pre-existing page of LOB_DATA : IAM_PAGE -- 1 pre-existing page of LOB_DATA : TEXT_MIX_PAGE (50% free space) -- 4 pre-existing page of LOB_DATA : TEXT_MIX_PAGE (0% free space) -- 3 new page of LOB_DATA : TEXT_MIX_PAGE (0% free space) -- 1 new page of LOB_DATA : TEXT_TREE_PAGE -- 7 new unallocated pages ---- 24 pages total -- DBCC PAGE(2, 1, 330, 3) WITH TABLERESULTS; -----------------------------------------------------------------------------------
Optional Paste Settings
Syntax Highlighting:
None
Bash
C
C#
C++
CSS
HTML
JSON
Java
JavaScript
Lua
Markdown (PRO members only)
Objective C
PHP
Perl
Python
Ruby
Swift
4CS
6502 ACME Cross Assembler
6502 Kick Assembler
6502 TASM/64TASS
ABAP
AIMMS
ALGOL 68
APT Sources
ARM
ASM (NASM)
ASP
ActionScript
ActionScript 3
Ada
Apache Log
AppleScript
Arduino
Asymptote
AutoIt
Autohotkey
Avisynth
Awk
BASCOM AVR
BNF
BOO
Bash
Basic4GL
Batch
BibTeX
Blitz Basic
Blitz3D
BlitzMax
BrainFuck
C
C (WinAPI)
C Intermediate Language
C for Macs
C#
C++
C++ (WinAPI)
C++ (with Qt extensions)
C: Loadrunner
CAD DCL
CAD Lisp
CFDG
CMake
COBOL
CSS
Ceylon
ChaiScript
Chapel
Clojure
Clone C
Clone C++
CoffeeScript
ColdFusion
Cuesheet
D
DCL
DCPU-16
DCS
DIV
DOT
Dart
Delphi
Delphi Prism (Oxygene)
Diff
E
ECMAScript
EPC
Easytrieve
Eiffel
Email
Erlang
Euphoria
F#
FO Language
Falcon
Filemaker
Formula One
Fortran
FreeBasic
FreeSWITCH
GAMBAS
GDB
GDScript
Game Maker
Genero
Genie
GetText
Go
Godot GLSL
Groovy
GwBasic
HQ9 Plus
HTML
HTML 5
Haskell
Haxe
HicEst
IDL
INI file
INTERCAL
IO
ISPF Panel Definition
Icon
Inno Script
J
JCL
JSON
Java
Java 5
JavaScript
Julia
KSP (Kontakt Script)
KiXtart
Kotlin
LDIF
LLVM
LOL Code
LScript
Latex
Liberty BASIC
Linden Scripting
Lisp
Loco Basic
Logtalk
Lotus Formulas
Lotus Script
Lua
M68000 Assembler
MIX Assembler
MK-61/52
MPASM
MXML
MagikSF
Make
MapBasic
Markdown (PRO members only)
MatLab
Mercury
MetaPost
Modula 2
Modula 3
Motorola 68000 HiSoft Dev
MySQL
Nagios
NetRexx
Nginx
Nim
NullSoft Installer
OCaml
OCaml Brief
Oberon 2
Objeck Programming Langua
Objective C
Octave
Open Object Rexx
OpenBSD PACKET FILTER
OpenGL Shading
Openoffice BASIC
Oracle 11
Oracle 8
Oz
PARI/GP
PCRE
PHP
PHP Brief
PL/I
PL/SQL
POV-Ray
ParaSail
Pascal
Pawn
Per
Perl
Perl 6
Phix
Pic 16
Pike
Pixel Bender
PostScript
PostgreSQL
PowerBuilder
PowerShell
ProFTPd
Progress
Prolog
Properties
ProvideX
Puppet
PureBasic
PyCon
Python
Python for S60
QBasic
QML
R
RBScript
REBOL
REG
RPM Spec
Racket
Rails
Rexx
Robots
Roff Manpage
Ruby
Ruby Gnuplot
Rust
SAS
SCL
SPARK
SPARQL
SQF
SQL
SSH Config
Scala
Scheme
Scilab
SdlBasic
Smalltalk
Smarty
StandardML
StoneScript
SuperCollider
Swift
SystemVerilog
T-SQL
TCL
TeXgraph
Tera Term
TypeScript
TypoScript
UPC
Unicon
UnrealScript
Urbi
VB.NET
VBScript
VHDL
VIM
Vala
Vedit
VeriLog
Visual Pro Log
VisualBasic
VisualFoxPro
WHOIS
WhiteSpace
Winbatch
XBasic
XML
XPP
Xojo
Xorg Config
YAML
YARA
Z80 Assembler
ZXBasic
autoconf
jQuery
mIRC
newLISP
q/kdb+
thinBasic
Paste Expiration:
Never
Burn after read
10 Minutes
1 Hour
1 Day
1 Week
2 Weeks
1 Month
6 Months
1 Year
Paste Exposure:
Public
Unlisted
Private
Folder:
(members only)
Password
NEW
Enabled
Disabled
Burn after read
NEW
Paste Name / Title:
Create New Paste
Hello
Guest
Sign Up
or
Login
Sign in with Facebook
Sign in with Twitter
Sign in with Google
You are currently not logged in, this means you can not edit or delete anything you paste.
Sign Up
or
Login
Public Pastes
My Log File
HTML 5 | 13 min ago
Untitled
JavaScript | 20 min ago
Local time
YAML | 40 min ago
syncmediadownloads...
Bash | 1 hour ago
KivyMd Main List C...
Python | 1 hour ago
Computercraft - Go...
Lua | 1 hour ago
syncmediadownloads
Bash | 1 hour ago
dumb and dumber
HTML | 1 hour ago
We use cookies for various purposes including analytics. By continuing to use Pastebin, you agree to our use of cookies as described in the
Cookies Policy
.
OK, I Understand
Not a member of Pastebin yet?
Sign Up
, it unlocks many cool features!