What is better? Using GUIDs or Integer values? This is been an age long (religious) debate and there are advocates in both camps stressing on the disadvantages of the other. Both implementations have their advantages and disadvantages. In this blogpost, we’ll see that the ultimate SQL Server answer is also valid for this debate: it all depends!
A 128-bit GUID (unique identifier) key is of course 4x larger than a 32-bit int key. However, there are a some advantages:
If you don’t need the key features of the unique identifier, use a numeric value instead
o Key features are:
USE test GO SET NOCOUNT ON; go CREATE TABLE DemoUnique ( c1 INT IDENTITY(1,1), c2 DATETIME DEFAULT GETDATE (), c3 VARCHAR(max) DEFAULT ‘Somevalue’, ) GO CREATE CLUSTERED INDEX CIX ON DemoUnique (c1) WITH (FILLFACTOR=0); GO INSERT INTO DemoUnique DEFAULT VALUES; GO 50000 SELECT OBJECT_NAME (ips.[object_id]) AS ‘Object Name’, si.name AS ‘Index Name’, ROUND (ips.avg_fragmentation_in_percent, 2) AS ‘Fragmentation’, ips.page_count AS ‘Pages’, ROUND (ips.avg_page_space_used_in_percent, 2) AS ‘Page Density’ FROM sys.dm_db_index_physical_stats (DB_ID (‘test’), NULL, NULL, NULL, ‘DETAILED’) ips CROSS APPLY sys.indexes si WHERE si.object_id = ips.object_id AND si.index_id = ips.index_id AND ips.index_level = 0; GO DROP TABLE DemoUnique go USE master go DROP DATABASE test
Results
Object Name | Index Name | Fragmentation | Pages | Page Density |
DemoUnique | CIX | 2,23 | 224 | 99,26 |
USE test go CREATE TABLE DemoUnique ( c1 UNIQUEIDENTIFIER DEFAULT NEWID(), c2 DATETIME DEFAULT GETDATE (), c3 VARCHAR(max) DEFAULT 'Somevalue', ) GO CREATE CLUSTERED INDEX CIX ON DemoUnique (c1) WITH (FILLFACTOR=95); GO INSERT INTO DemoUnique DEFAULT VALUES; GO 50000 SELECT OBJECT_NAME (ips.[object_id]) AS 'Object Name', si.name AS 'Index Name', ROUND (ips.avg_fragmentation_in_percent, 2) AS 'Fragmentation', ips.page_count AS 'Pages', ROUND (ips.avg_page_space_used_in_percent, 2) AS 'Page Density' FROM sys.dm_db_index_physical_stats (DB_ID ('test'), NULL, NULL, NULL, 'DETAILED') ips CROSS APPLY sys.indexes si WHERE si.object_id = ips.object_id AND si.index_id = ips.index_id AND ips.index_level = 0; GO DROP TABLE DemoUnique go USE master go DROP DATABASE test
Results
Object Name | Index Name | Fragmentation | Pages | Page Density |
DemoUnique | CIX | 99,33 | 446 | 66,46 |
USE test GO SET NOCOUNT ON; go CREATE TABLE DemoUnique ( c1 UNIQUEIDENTIFIER DEFAULT NEWSEQUENTIALID(), c2 DATETIME DEFAULT GETDATE (), c3 VARCHAR(max) DEFAULT 'Somevalue', ) GO CREATE CLUSTERED INDEX CIX ON DemoUnique (c1) WITH (FILLFACTOR=100); GO INSERT INTO DemoUnique DEFAULT VALUES; GO 50000 SELECT OBJECT_NAME (ips.[object_id]) AS 'Object Name', si.name AS 'Index Name', ROUND (ips.avg_fragmentation_in_percent, 2) AS 'Fragmentation', ips.page_count AS 'Pages', ROUND (ips.avg_page_space_used_in_percent, 2) AS 'Page Density' FROM sys.dm_db_index_physical_stats (DB_ID ('test'), NULL, NULL, NULL, 'DETAILED') ips CROSS APPLY sys.indexes si WHERE si.object_id = ips.object_id AND si.index_id = ips.index_id AND ips.index_level = 0; GO DROP TABLE DemoUnique go USE master go DROP DATABASE test
Results
Object Name | Index Name | Fragmentation | Pages | Page Density |
DemoUnique | CIX | 2,01 | 298 | 99,48 |
CREATE DATABASE Test GO USE test go CREATE TABLE DemoUnique ( c1 UNIQUEIDENTIFIER DEFAULT NEWID () ROWGUIDCOL, c2 DATETIME DEFAULT GETDATE (), c3 VARCHAR(max) DEFAULT 'Somevalue'); CREATE NONCLUSTERED INDEX Demo_W_Unique_NCL ON DemoUnique (C2,C1); CREATE NONCLUSTERED INDEX Demo_W_Incl_Unqiue ON DemoUnique (C2) INCLUDE (C1); CREATE CLUSTERED INDEX CIX ON DemoUnique (c2) WITH (FILLFACTOR=95); GO INSERT INTO DemoUnique DEFAULT VALUES; GO 50000 SELECT OBJECT_NAME (ips.[object_id]) AS 'Object Name', si.name AS 'Index Name', ROUND (ips.avg_fragmentation_in_percent, 2) AS 'Fragmentation', ips.page_count AS 'Pages', ROUND (ips.avg_page_space_used_in_percent, 2) AS 'Page Density' FROM sys.dm_db_index_physical_stats (DB_ID ('test'), NULL, NULL, NULL, 'DETAILED') ips CROSS APPLY sys.indexes si WHERE si.object_id = ips.object_id AND si.index_id = ips.index_id AND ips.index_level = 0; GO DROP TABLE DemoUnique go USE master go DROP DATABASE test
Results
Object Name | Index Name | Fragmentation | Pages | Page Density |
DemoUnique | CIX | 2,52 | 318 | 99,54 |
DemoUnique | Demo_W_Unique_NCL | 43,77 | 345 | 65,35 |
DemoUnique | Demo_W_Incl_Unique | 2,65 | 226 | 99,77 |
CREATE DATABASE Test GO USE test go CREATE TABLE DemoUnique ( c2 DATETIME DEFAULT GETDATE (), c3 VARCHAR(max) DEFAULT 'Somevalue', c4 CHAR(64) DEFAULT CONVERT(VARCHAR(24),GETDATE(),126) +'|'+ CAST(NEWID() AS VARCHAR(40)) -- Comb value ) GO CREATE NONCLUSTERED INDEX Demo_W_Comb_NCL ON DemoUnique (c4); CREATE CLUSTERED INDEX CIX ON DemoUnique (c2) WITH (FILLFACTOR=95); GO INSERT INTO DemoUnique DEFAULT VALUES; GO 50000 SELECT OBJECT_NAME (ips.[object_id]) AS 'Object Name', si.name AS 'Index Name', ROUND (ips.avg_fragmentation_in_percent, 2) AS 'Fragmentation', ips.page_count AS 'Pages', ROUND (ips.avg_page_space_used_in_percent, 2) AS 'Page Density' FROM sys.dm_db_index_physical_stats (DB_ID ('test'), NULL, NULL, NULL, 'DETAILED') ips CROSS APPLY sys.indexes si WHERE si.object_id = ips.object_id AND si.index_id = ips.index_id AND ips.index_level = 0; GO DROP TABLE DemoUnique go USE master go DROP DATABASE test
Results
Object Name | Index Name | Fragmentation | Pages | Page Density |
DemoUnique | CIX | 1,99 | 403 | 99,31 |
DemoUnique | Demo_W_Comb_NCL | 49,88 | 433 | 76,56 |
If you don’t have a specific reason to use GUIDs, use (BIG)INTs.
Try not to use a GUID as an (first) index key
If you need a GUID as clustered key, make sure you address the randomness issue: use sequential guids
If you need a GUID as nonclustered key, try to add them as an include if they are nonsequential
© 2022 Kohera
Crafted by
© 2022 Kohera
Crafted by