How are default column values stored?

An interesting question came up in class yesterday: how is a default column value stored, and what if some rows exist when a column is added and then the default value changes?

An example scenario is this:

  • Step 1: Create a table with two columns
  • Step 2: Add 10 rows
  • Step 3: Add a third column to the table with a non-null default
  • Step 4: Drop the default for the third column
  • Step 5: Add a new default for the third column

And selecting the initial 10 rows can be demonstrated to return the 3rd column using the initial default set in step 3. (It makes no difference if any rows are added between steps 3 and 4.)

This means that there *must* be two default values stored when a new column is added: one for the set of already-existing rows that don’t have the new column and one for any new rows. Initially these two default values will be the same, but the one for new rows can change (e.g. in steps 4 and 5 above) with breaking the old rows. This works because after the new column is added (step 3 above), it’s impossible to add any more rows that *don’t* have the new column.

And this is exactly how it works. Let’s investigate!

Firstly I’ll create a simple database and test table and insert 10 rows. I’ll use the simple recovery model so I can clear the log by doing a checkpoint:

CREATE DATABASE [Company];
ALTER DATABASE [Company] SET RECOVERY SIMPLE;
GO
USE [Company];
GO

-- Create a test table to use
CREATE TABLE [Test] ([c1] INT IDENTITY, [c2] INT AS ([c1]));
GO
INSERT INTO [Test] DEFAULT VALUES;
GO 10
SELECT * FROM [Test];
GO
c1          c2
----------- -----------
1           1
2           2
3           3
4           4
5           5
6           6
7           7
8           8
9           9
10          10

Now I’ll clear the log, add the third column with the default, and look to see which system tables were added to because of addition:

CHECKPOINT;
GO

-- Add column with default value
ALTER TABLE [Test] ADD [c3] CHAR (6) NOT NULL CONSTRAINT [OriginalDefault] DEFAULT 'BEFORE';
GO

SELECT [AllocUnitName] FROM fn_dblog (NULL, NULL)
WHERE [Operation] = 'LOP_INSERT_ROWS';
GO
AllocUnitName
-----------------------
sys.syscolpars.clst
sys.syscolpars.nc
sys.sysrscols.clst
sys.sysseobjvalues.clst
sys.sysschobjs.clst
sys.sysschobjs.nc1
sys.sysschobjs.nc2
sys.sysschobjs.nc3
sys.sysobjvalues.clst

Cool. These system tables have the following functions:

  • sys.syscolpars: table column definitions (relational metadata)
  • sys.sysrscols: rowset column definitions (Storage Engine metadata – info to allow interpretation of record structures on pages)
  • sys.seobjvalues: various Storage Engine values of different uses
  • sys.sysschobjs: relational objects (e.g. tables, constraints)
  • sys.sysobjvalues: various relational values of different uses

I’m going to look in these to find how the inserted rows relate to our table. I’m going to need a few IDs first (using my handy procedure to do that):

EXEC sp_allocationmetadata N'Test';
GO
Object Name Index ID Partition ID      Alloc Unit ID     Alloc Unit Type First Page Root Page First IAM Page
----------- -------- ----------------- ----------------- --------------- ---------- --------- --------------
Test        0        72057594040549376 72057594045792256 IN_ROW_DATA     (1:247)    (0:0)     (1:288)

And now I can query those system tables. Note that they’re ‘hidden’ system tables so you can’t query them unless you connect using the Dedicated Admin Connection. Easiest way to do that is to prefix your SSMS connection string with ‘admin:’ (and if you’re connecting to a remote server, the server needs to have sp_configure option remote admin connections enabled). Make sure you use the correct database after connecting, as the DAC drops you into master.

SELECT * FROM sys.syscolpars WHERE [id] = OBJECT_ID (N'Test');
GO
id        number colid name xtype utype length prec scale collationid status maxinrow xmlns dflt        chk idtval
--------- ------ ----- ---- ----- ----- ------ ---- ----- ----------- ------ -------- ----- ----------- --- ---------
245575913 0      1     c1   56    56    4      10   0     0           5      4        0     0           0   0x0A000000010000000100000000
245575913 0      2     c2   56    56    4      10   0     0           209    4        0     0           0   NULL
245575913 0      3     c3   175   175   6      0    0     872468488   3      6        0     261575970   0   NULL

These are the relational definitions of the columns in the table, and you can see that c3 is listed as having a default constraint, with ID 261575970.

SELECT * FROM sys.sysschobjs WHERE [id] = 261575970;
GO
id          name            nsid nsclass status type pid       pclass intprop created                 modified                status2
----------- --------------- ---- ------- ------ ---- --------- ------ ------- ----------------------- ----------------------- -------
261575970   OriginalDefault 1    0       131072 D    245575913 1      3       2017-04-26 13:37:42.463 2017-04-26 13:37:42.463 0

This is the constraint named OriginalDefault with type D (default) and the default value has ID 245575913.

SELECT * FROM sys.sysobjvalues WHERE [objid] = 261575970;
GO
valclass objid     subobjid valnum value imageval
-------- --------- -------- ------ ----- ----------------------
1        261575970 0        0      2     0x28274245464F52452729

And the imageval column has the default value as hex-encoded ASCII values. Using the ASCII map on Wikipedia, the value is (‘BEFORE’), including the parentheses.

So that’s the default value for new rows. What about the default value for rows that already exist?

SELECT * FROM sys.sysrscols WHERE [rsid] = 72057594040549376;
GO
rsid              rscolid hbcolid rcmodified ti   cid       ordkey maxinrowlen status offset nullbit bitpos colguid
----------------- ------- ------- ---------- ---- --------- ------ ----------- ------ ------ ------- ------ -------
72057594040549376 1       1       10         56   0         0      0           128    4      1       0      NULL
72057594040549376 2       2       10         56   0         0      0           128    8      2       0      NULL
72057594040549376 3       3       0          1711 872468488 0      0           640    12     3       0      NULL

These are the Storage Engine definitions of the columns in the table. The status value indicates that the value may not be in the row, and where to get the default value from.

SELECT * FROM sys.sysseobjvalues WHERE [id] = 72057594040549376;
GO
valclass id                subid valnum value  imageval
-------- ----------------- ----- ------ ------ --------
1        72057594040549376 3     0      BEFORE NULL

And there is the Storage Engine storage for the default value for the c3 column for those rows that existed before c3 was added.

Now I’ll checkpoint, drop the default constraint, and look to see what happened in the log:

CHECKPOINT;
GO

ALTER TABLE [Test] DROP CONSTRAINT [OriginalDefault];
GO

SELECT [AllocUnitName] FROM fn_dblog (NULL, NULL)
WHERE [Operation] = 'LOP_DELETE_ROWS';
GO
AllocUnitName
---------------------
sys.sysobjvalues.clst
sys.sysschobjs.nc1
sys.sysschobjs.nc2
sys.sysschobjs.nc3
sys.sysschobjs.clst

So that’s the relational default value being deleted, in the reverse order from how it was added. Note that the Storage Engine default value wasn’t deleted.

Now I’ll create a new default constraint for the c3 column:

CHECKPOINT;
GO

ALTER TABLE [Test] ADD CONSTRAINT [NewDefault] DEFAULT 'AFTER' FOR [c3];
GO

SELECT [AllocUnitName] FROM fn_dblog (NULL, NULL)
WHERE [Operation] = 'LOP_INSERT_ROWS';
GO
AllocUnitName
---------------------
sys.sysschobjs.clst
sys.sysschobjs.nc1
sys.sysschobjs.nc2
sys.sysschobjs.nc3
sys.sysobjvalues.clst

And doing the various queries again gets us to the new relational column stored default value of (‘AFTER’), including the parentheses.

So just to prove what I said before investigating, I’ll add ten new rows, which will have the c3 value AFTER, and then query the table and I’ll see that the initial ten rows that don’t have c3 in will be given the original default value of BEFORE:

INSERT INTO [Test] DEFAULT VALUES;
GO 10

SELECT * FROM [Test];
GO
c1          c2          c3
----------- ----------- ------
1           1           BEFORE
2           2           BEFORE
3           3           BEFORE
4           4           BEFORE
5           5           BEFORE
6           6           BEFORE
7           7           BEFORE
8           8           BEFORE
9           9           BEFORE
10          10          BEFORE
11          11          AFTER 
12          12          AFTER 
13          13          AFTER 
14          14          AFTER 
15          15          AFTER 
16          16          AFTER 
17          17          AFTER 
18          18          AFTER 
19          19          AFTER 
20          20          AFTER 

Hope you found this interesting! (And don’t forget to drop your DAC connection.)

SQLskills SQL101: Restoring to an earlier version

As Kimberly blogged about recently, SQLskills is embarking on a new initiative to blog about basic topics, which we’re calling SQL101. We’ll all be blogging about things that we often see done incorrectly, technologies used the wrong way, or where there are many misunderstandings that lead to serious problems. If you want to find all of our SQLskills SQL101 blog posts, check out SQLskills.com/help/SQL101.

One of the questions I get asked every so often is whether it’s possible to attach or restore a database to an earlier version of SQL Server. Usually the explanation behind the question is that the person accidentally attached the only copy of their database to a newer version than they wanted, or they were just trying out a pre-release version and now want to put their database back into their production system.

So is this possible? The very simple answer is: No.

SQL Server is down-level compatible but is not up-level compatible. This means you can take a database from an earlier version and attach/restore it to a newer version (I explained about this in a post here), but you can’t go backwards to an earlier version.

Why is this the case?

Upgrade steps

An upgrade, whether intentional or accidental, is a one-way operation and it is extremely difficult to reverse its effects. When you upgrade between versions of SQL Server, a series of upgrade steps are performed on the database. Each step usually involves some physical changes to the database, and each step increases the physical version number of the database.

For example, one of the major changes performed when a database was upgraded from SQL Server 2000 to SQL Server 2005 (yes, old and unsupported, but an easy-to-explain example) was to change the structure of the database’s system catalogs (often called the system tables or database metadata) that hold various metadata about tables, indexes, columns, allocations, and other details regarding the relational and physical structure of the database.

As each of these upgrade steps is performed, the database version number is increased. Here are some examples:

  • SQL Server 2016 databases have version number 852
  • SQL Server 2014 databases have version number 782
  • SQL Server 2012 databases have version number 706
  • SQL Server 2008 R2 databases have version number 661

This version number allows SQL Server to know the last upgrade step performed on the database, and whether the in-use SQL Server version can understand the database being attached/restored.

Here’s an example of restoring a SQL Server 2012 database to a SQL Server 2014 server:

RESTORE DATABASE [Company2012]
FROM DISK = N'D:\SQLskills\Company2012_Full.bak'
WITH REPLACE;
GO
Processed 280 pages for database 'Company', file 'Company' on file 1.
Processed 3 pages for database 'Company', file 'Company_log' on file 1.
Converting database 'Company' from version 706 to the current version 782.
Database 'Company' running the upgrade step from version 706 to version 770.
Database 'Company' running the upgrade step from version 770 to version 771.
Database 'Company' running the upgrade step from version 771 to version 772.
Database 'Company' running the upgrade step from version 772 to version 773.
Database 'Company' running the upgrade step from version 773 to version 774.
Database 'Company' running the upgrade step from version 774 to version 775.
Database 'Company' running the upgrade step from version 775 to version 776.
Database 'Company' running the upgrade step from version 776 to version 777.
Database 'Company' running the upgrade step from version 777 to version 778.
Database 'Company' running the upgrade step from version 778 to version 779.
Database 'Company' running the upgrade step from version 779 to version 780.
Database 'Company' running the upgrade step from version 780 to version 781.
Database 'Company' running the upgrade step from version 781 to version 782.
RESTORE DATABASE successfully processed 283 pages in 0.022 seconds (100.430 MB/sec).

Up-level compatibility (or lack thereof…)

Versions of SQL Server cannot read databases upgraded to more recent versions of SQL Server – for instance, SQL Server 2012 cannot read a database that’s been upgraded to SQL Server 2014. This is because older versions do not have the code needed to interpret the upgraded structures and database layout.

Here’s an example of trying to restore a SQL Server 2014 database to a SQL Server 2012 server:

RESTORE DATABASE [Company2014]
FROM DISK = N'D:\SQLskills\Company2014_Full.bak'
WITH REPLACE;
GO
Msg 3169, Level 16, State 1, Line 51
The database was backed up on a server running version 12.00.4422. That version is incompatible with this server, which is running version 11.00.5343. Either restore the database on a server that supports the backup, or use a backup that is compatible with this server.
Msg 3013, Level 16, State 1, Line 51
RESTORE DATABASE is terminating abnormally.

In earlier versions, the messages weren’t always quite as nice and easy to understand.

And some people confuse database compatibility level with the database version. Compatibility level has nothing to do with up-level compatibility – it just changes how some query processor features behave.

Summary

The simple thing to bear in mind is not to attach the only copy of your database to a newer version. It’s always better to restore a copy of a database, then you’ve still got the original database to fall back on, for whatever reason. This applies even if you’re deliberately performing an upgrade – I’d still want to keep the older copy of the database around in case some problem occurs with the upgrade.

If you *have* attached your only copy of the database to a newer version and want to go back to an earlier version, your only option is to script out the database structure, create the database again on the older version, and then transfer all the data from the newer version to the older version. Very tedious.

Hope you found this helpful!

PS There’s a comment below asking whether you can move back to an earlier SP or CU. Yes, for user databases, as long as the newer SP/CU didn’t change the physical version number (and none of them since 2005 SP2 and 2008 SP2 have done that).

Why PFS pages cannot be repaired

Last week there was a short discussion on Twitter about why PFS pages (damaged header, not individual PFS bytes) can’t be repaired (prompted by a #sqlhelp question about why they can’t be single-page restored, like other per-database allocation bitmaps). Just for the record, they can’t be fixed by automatic page repair in a mirror or AG either.

PFS pages occur every 8088 pages in every data file and store a byte of information about itself and the following 8087 pages. The most important piece of information it stores is whether a page is allocated (in use) or not. You can read more about PFS pages and the other per-database allocation bitmaps in this blog post.

So why can’t they be rebuilt by DBCC CHECKDB, when all the other per-database allocation bitmaps can?

The answer is that the is-this-page-allocated-or-not information is not duplicated anywhere else in the database, and it’s impossible to reconstruct it in all cases.

You might think that DBCC CHECKDB could work out which pages are allocated by inferring that state if a page is linked to in some way from another page that’s known to be allocated, and it could do that, except for the case of a heap with no nonclustered indexes.

If a heap has no nonclustered indexes, there is no other structure in the database that links to any of the data pages in the heap. Therefore, without the information in a PFS page, there’s no way to tell which of the pages contained in extents allocated to the heap are actually allocated or not. This is because SQL Server does not touch a page when it is deallocated, so there’s nothing on a page that indicates whether a page is currently allocated or has been deallocated.

So what if DBCC CHECKDB can tell that there are no such cases in the database?

The answer is that the algorithm to rebuild a PFS page given the links from other pages to pages covered by that PFS range is extremely complicated and would involve searching through the entire database, reading and processing all pages a second time *after* they’ve been repaired, looking for linkages to pages in the broken range. While it sounds technically possible, when scoping out writing such an algorithm back in 2001-2002, I quickly ran into run-time and complexity challenges that made the work entirely infeasible.

It’s also not possible to just mark all the pages allocated – because then allocation-order scans would come across potentially unformatted pages and fail. It would also break backups that use WITH CHECKSUM. Such an algorithm could be made to work (in the absence of heaps with no nonclustered indexes), but has the same problems as the algorithm above.

So – PFS pages can’t be repaired, and unless the database structure changes to mirror that allocation information in some way, I don’t see that changing at any point in the future.

Hope you found this interesting!