Blog Post

SQL Server: Understanding GAM and SGAM Pages

,

We know that SQL server stores the data in 8 KB pages. An extent is made up of 8 physically contiguous pages.When we create a database, the data files will be logically divided into the pages and extents.Later, when user objects are created, the pages are allocated to them to store the data.GAM (Global Allocation Map) and SGAM (Shared Global Allocation Map) pages are used to track the space allocation in SQL Server. In this post, let us discuss about space allocation in SQL server and how GAM and SGAM helps in the space allocation.
In SQL server there are two types of extents: 
Uniform Extent: These are the extents owned by single user objects. All 8 pages of these extents can be used by a single object, the owning object.

Mixed Extent:These are the extents owned by multiple user objects. There is a  possibility of each page in this  extent, that might be allocated to 8 different user objects. Each of the eight pages in the extent can be owned by  different objects.

To make space allocation more optimize, SQL server will not allocate pages from uniform extent to a table or index if its size is less than 8 pages. Let us try a sample .

USE Mydb

GO
CREATE TABLE TestSpaceAllocation(
  
Name CHAR(8000)
)

GOINSERT INTO TestSpaceAllocation VALUES('John')
GO 26 --Insert 26 records 
DBCC IND('MyDb','TestSpaceAllocation',1)


For the usage of DBCC IND refer the earlier post

The output will looks like as given below:




From the output, it is clear that, the first 8 pages are not from single extent . There is a gap between page number 187 and 211, remaining 8 pages are physically contiguous (8 page number are in sequential order). While looking into the fragmentation level in your environment, you might have noticed small tables with higher level of fragmentation. This higher fragmentation will not reduce even if you rebuild the index.The reason behind this is due to the allocation of first eight pages from the mixed extent.Refer the post Measuring Fragmentation to learn about Fragmentation 
SQL sever allocates pages for new table or indexes from mixed extents.Once the tables grow beyond 8 pages, SQL server has to allocate page from uniform extent. When a table or index need more space to accommodate the new or modified data, SQL server has to allocate page for the table or index. If the size of the table or index is less than 8 pages, SQL server has to locate a page from mixed extent to allocate. If the size is more than 8 pages, SQL server has to locate the page from uniform extent. SQL server uses two types of pages to optimize this allocation process.
GAM(Global Allocation Map): GAM pages records what extents have been allocated for any use. GAM has bit for every extent. If the bit is 1, the corresponding extent is free, if the bit is 0, the corresponding extent is in use as uniform or mixed extent.A GAM page can hold information of around 64000 extents. That is, a GAM page can hold information of (64000X8X8)/1024 = 4000 MB approximately. In short,  a data file of size 7 GB will have two GAM pages.
SGAM (Shares Global Allocation Map): SGAM pages record what extents are currently being used as mixed extent and also have at least one unused page. SGAM has bit for every extent. If the bit is 1, the corresponding extent is used as a mixed extent and has at least one page free to allocate. If the bit is 0, the extent is either not used as a mixed extent or it is mixed extent and with all its pages being used. A SGAM page can hold information of 64000 extents. That is, a SGAM page can hold information of (64000X8X8)/1024 = 4000 MB. In short, a data file of size 7 GB will have two SGAM page.
GAM and SGAM pages helps the database engine in extent management. To allocate an extent, the database engine searches the GAM page for a bit 1 and set the bit to 0. If that extent is allocating as mixed extent, it sets  the corresponding extent's bit in SGAM page to 1. If that extent is allocating as uniform extent, there is no need to change the corresponding SGAM bit. To find a mixed extent with free pages, the database engine searches the SGAM page for a bit 1. If there is no free extent, the data file is full. To deallocate an extent, the database engine sets the corresponding GAM bit set to 1 and SGAM bit to 0.

In any data file, the third page(page no 2) is GAM and fourth page (page no 3) is  SGAM page. The first page (page no 0) is file header and second page (page no 1) is PFS (Page Free Space) page.  We can see the GAM and SGAM pages using DBCC page command. Refer earlier post for the usage of DBCC page 

DBCC TRACEON(3604)
GO
DBCC page('adventureworks2008',1,2,3)

The last part of the out put is :













First line says that, all extents between the extent starts at  page no 0 and  22400 are allocated .That means page numbers from 0 to 22407 are part of the allocated extents.Second line says that, all extents between the extent start at  page number 22408 and  2416 are not allocated .That means page number from 

22408  to 22423 are part of extents which are not allocated. Third line says that, extent start at page no 22424 is allocated. That means page number from  

22424   to 

22431 are part of the allocated extent. Let us do DBCC page for one allocated page(22400) and one not allocated page (22408)

DBCC page('adventureworks2008',1,22400,1)










After the page header, in the allocation status section, it has mentioned the GAM page, to which the page belongs  to and the status of the extent as  ALLOCATED . For the  page 22408  it will be same GAM page but status will be NOT ALLOCATED.


Let us see the SGAM page
DBCC page('adventureworks2008',1,3,3)


The last part of the output will look like as given below.










It says that extents between extent starts at page numbers 0 and  11752  are not allocated, which means these extents are not allocated at all or are uniform extents or mixed extents with no free pages. The second lines says, the extent start at page number 11760 is a mixed extent and has at least one free page.

If you liked this post, do like my page on FaceBook 


References:

  •  Microsoft® SQL Server® 2008 Internals by Kalen Delaney, Paul S. Randal, Kimberly L. Tripp , Conor Cunningham , Adam Machanic. ISBN :0-7356-2624-3
  • MSDN 

    http://msdn.microsoft.com/en-us/library/ms175195(v=sql.100).aspx


Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating