Changing a column from NOT NULL to NULL - What's going on under the hood?
As alluded to by @Souplex in the comments one possible explanation might be if this column is the first NULL
-able column in the non clustered index it participates in.
For the following setup
CREATE TABLE Foo
(
A UNIQUEIDENTIFIER NOT NULL DEFAULT NEWSEQUENTIALID() PRIMARY KEY,
B CHAR(1) NOT NULL DEFAULT 'B'
)
CREATE NONCLUSTERED INDEX ix
ON Foo(B);
INSERT INTO Foo
(B)
SELECT TOP 100000 'B'
FROM master..spt_values v1,
master..spt_values v2
sys.dm_db_index_physical_stats shows the non clustered index ix
has 248 leaf pages and a single root page.
A typical row in an index leaf page looks like
And in the root page
Then running...
CHECKPOINT;
GO
ALTER TABLE Foo ALTER COLUMN B CHAR(1) NULL;
SELECT Operation,
Context,
ROUND(SUM([Log Record Length]) / 1024.0,1) AS [Log KB],
COUNT(*) as [OperationCount]
FROM sys.fn_dblog(NULL,NULL)
WHERE AllocUnitName = 'dbo.Foo.ix'
GROUP BY Operation, Context
Returned
+-----------------+--------------------+-------------+----------------+
| Operation | Context | Log KB | OperationCount |
+-----------------+--------------------+-------------+----------------+
| LOP_SET_BITS | LCX_GAM | 4.200000 | 69 |
| LOP_FORMAT_PAGE | LCX_IAM | 0.100000 | 1 |
| LOP_SET_BITS | LCX_IAM | 4.200000 | 69 |
| LOP_FORMAT_PAGE | LCX_INDEX_INTERIOR | 8.700000 | 3 |
| LOP_FORMAT_PAGE | LCX_INDEX_LEAF | 2296.200000 | 285 |
| LOP_MODIFY_ROW | LCX_PFS | 16.300000 | 189 |
+-----------------+--------------------+-------------+----------------+
Checking the index leaf again the rows now look like
and the rows in the upper level pages as below.
Each row has been updated and now contains two bytes for the column count along with another byte for the NULL_BITMAP.
Due to the extra row width the non clustered index now has 285 leaf pages and now two intermediate level pages along with the root page.
The execution plan for the
ALTER TABLE Foo ALTER COLUMN B CHAR(1) NULL;
looks as follows
This creates a brand new copy of the index rather than updating the existing one and needing to split pages.
It will definitely re-create the non clustered index and not just update metadata. This is tested on SQL 2014 and should really not be tested on a production system:
CREATE TABLE [z](
[a] [int] IDENTITY(1,1) NOT NULL,
[b] [int] NOT NULL,
CONSTRAINT [c_a] PRIMARY KEY CLUSTERED ([a] ASC))
go
CREATE NONCLUSTERED INDEX [nc_b] on z (b asc)
GO
insert into z (b)
values (1);
And now for the fun part:
DBCC IND (0, z, -1)
This will give us the database pages where the table and the non clustered index are stored.
Find the PagePID
where IndexID
is 2 and PageType
is 2, and then do the following:
DBCC TRACEON(3604) --are you sure that you are allowed to do this?
and then:
dbcc page (0, 1, PagePID, 3) with tableresults
Notice that there is a null bitmap in the header:
Now let's do:
alter table z alter Column b int null;
If you are really impatient you can try to run the dbcc page
command again but it will fail, so let's check the allocation again with DBCC IND (0, z, -1)
. The page will have moved as if by magic.
So changing nullability of a column will affect the storage of non clustered indexes that cover that column, as metadata needs to be updated and you should not need to rebuild the indexes afterwards.
Many ALTER TABLE ... ALTER COLUMN ...
operations can be performed ONLINE
starting with SQL Server 2016, but:
ALTER TABLE (Transact-SQL)
- Altering a column from
NOT NULL
toNULL
is not supported as an online operation when the altered column is referenced by nonclustered indexes.