SQL Server versions:
The internal database versions for SQL Server aren't clearly documented in the Microsoft documentation.
SQL Server Version | Internal Database Version | Database Compatibility Level |
---|---|---|
2014 | 782 | 120 |
2012 | 706 | 110 |
2012 CTP1 (2011 Denali) | 684 | 110 |
2008 R2 | 660 / 661 | 100 |
2008 | 655 | 100 |
2005 SP2+ with VarDecimal enabled | 612 | 90 |
2005 | 611 | 90 |
2000 | 539 | 80 |
7.0 | 515 | 70 |
6.5 | ? | 65 |
6.0 | ? | 60 |
Legend: ? = still investigating, RTM = Release to manufacturing, SPn = Service Pack n
SQL Server Version | Compatibility Level | Internal Database Version | Build |
SQL Server 2012 RTM | 110 | 706 | 11.0.2100.60 |
SQL Server 2008 R2 | 100 | 665 | 10.50.xxxx |
SQL Server 2008 | 100 | 661 | 10.00.xxxx |
SQL Server 2005 SP2 | 90 | 612 | 9.00.xxxx |
SQL Server 2005 | 90 | 611 | 9.00.xxxx |
SQL Server 2000 | 80 | 539 | 8.00.xxx(x) |
SQL Server 7 | 65 | 515 | 7.00.xxx(x) |
Six Ways to Find SQL Server Internal Version Number (SQL Server 2012 Version 706)
The Internal version number of the SQL Server code with which the database was created. It is not a supported value from Microsoft. Future compatibility is not guaranteed but it works for SQL Server 2008 and 2012.
Howerver, many users are coming across this value in error message when they were trying to restore/copy database from a lower version instance. You may not find a good source for documentation about this value. I compiled six ways(T-SQL query) to get this value for your database: the first two are to restore from the the bak file Header and the four other ways are to query online database to get this Internal Version Number.
The quickest way to get this Version value for an online database is to query the sysdatabase:
SELECT name,version FROM sys.sysdatabases
The details of these six methods:
A. Extract this value from backup file Header Infomation:
1. Run the following command from most recent SSMS ( if you run from lower version SSMS, you may not get this value):
RESTORE HEADERONLY FROM DISK=N’c:\backup\sampleDB.bak’
Check these columns from the result panel:DatabaseName,DatabaseVersion,DatabaseCreationDate
The DatabaseVersionison (Internal Version Number) are one of these values:
706(SQLServer 2012), 665/661(SQLServer 2008/R2),611/612(SQLServer 2005/SP2) and539(SQLServer 2000)
2. Run this script
sp_configure ‘show advanced options’,1
GO
reconfigure
Go
sp_configure ‘Ad Hoc Distributed Queries’, 1
GO
reconfigure
GO
SELECT * INTO #myVersion
FROM OPENROWSET(‘SQLNCLI’,’Server=USWDM2ML5054498\SQL08R2;Trusted_Connection=yes’,
‘EXEC(”SET FMTONLY OFF RESTORE HEADERONLY FROM DISK =””C:\backupserver\sql_backups\mytest1.bak”””)’) AS t
SELECT DatabaseName,DatabaseVersion,DatabaseCreationDate FROM #myVersion
DROP TABLE #myVersion
B. Database Online methods:
1. Get the version value from DATABASEPROPERTYEX: (DATABASEPROPERTY still works but deprecated)
Run the following query from SSMS for your database:
Run the following query from SSMS for your database:
SELECT SERVERPROPERTY(‘productversion’) as [Product version],
SERVERPROPERTY (‘productlevel’) as [Product level] ,
SERVERPROPERTY (‘edition’) as [Edition],
DATABASEPROPERTYEX((select DB_Name()),’Version’) as [Internal Version Number]
–,DATABASEPROPERTY((select DB_Name()),’Version’) as [Internal Version Number--Deprecated]
,(select DB_Name()) as DBName,
(SELECT COMPATIBILITY_LEVEL FROM SYS.DATABASES WHERE NAME = (select DB_Name())) as compatibilityLevel
SERVERPROPERTY (‘productlevel’) as [Product level] ,
SERVERPROPERTY (‘edition’) as [Edition],
DATABASEPROPERTYEX((select DB_Name()),’Version’) as [Internal Version Number]
–,DATABASEPROPERTY((select DB_Name()),’Version’) as [Internal Version Number--Deprecated]
,(select DB_Name()) as DBName,
(SELECT COMPATIBILITY_LEVEL FROM SYS.DATABASES WHERE NAME = (select DB_Name())) as compatibilityLevel
2.Retrieve the value from sysdatabase
DECLARE @dbName VARCHAR(128)
SET @dbName=(SELECT Db_name())
SELECT name, version FROM sys.sysdatabases WHERE name = @dbName
SET @dbName=(SELECT Db_name())
SELECT name, version FROM sys.sysdatabases WHERE name = @dbName
3.Use DBCC Command DBINFO (yourdbName)
3.1 Get the values from the result of DBINFO (yourdbName)
You need to turn on undocumented trace flag 3604 to run DBINFO and check the value ofdbi_version from the message screen.
DBCC TRACEON (3604)
GO
–get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
You need to turn on undocumented trace flag 3604 to run DBINFO and check the value ofdbi_version from the message screen.
DBCC TRACEON (3604)
GO
–get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
DBCC DBINFO (@dbName)
GO
GO
DBCC TRACEOFF (3604)
GO
GO
There is another value for this database that may be useful to your: dbi_createVersion
You will know the version this database is created from.
You will know the version this database is created from.
3.2 Get these values from a temp table
You can run the following query to get the value in atable:
DBCC TRACEON (3604)
GO
CREATE TABLE #t (ParentObject VARCHAR (255), [Object] VARCHAR (255), Field VARCHAR (500), [Value] VARCHAR (500))
––get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
insert into #t
exec (‘DBCC DBINFO (‘+@dbName+’) WITH TABLERESULTS’)
GO
select [dbi_dbname],[dbi_version],[dbi_createVersion] from (SELECT Field, Value FROM #t) src
PIVOT (Max(Value) For Field IN ([dbi_dbname],[dbi_version],[dbi_createVersion])) pvt
drop table #t
DBCC TRACEOFF (3604)
GO
3.3 Get these values on the fly:
<code>
EXEC sp_configure ‘show advanced options’,1
GO
reconfigure
Go
EXEC sp_configure ‘Ad Hoc Distributed Queries’, 1
GO
reconfigure
GO
DBCC TRACEON (3604)
GO
declare @dbName varchar(128) = (select DB_name())
declare @cmd varchar(1000);
select @cmd = ‘SET FMTONLY OFF;SET NOCOUNT ON; EXEC(”” DBCC DBINFO (‘+@dbName+’) WITH TABLERESULTS””)';
EXEC(‘SELECT * INTO myVersion from OPENROWSET(”SQLNCLI”,”Server=USWDM2ML5054498\SQL08R2;Trusted_Connection=yes;”,”’ + @cmd + ”’) AS t;’ )
SELECT Field, Value FROM myVersion
WHERE Field =’dbi_createVersion’ or Field =’dbi_crdate’ or Field =’dbi_Version’ or Field =’dbi_dbname’
DROP TABLE myVersion;
DBCC TRACEOff (3604)
GO
</code>
4.Use DBCC Command PAGE (yourdbName,1,9,3)
4.1 Get the value from the result of PAGE (yourdbName,1,9,3)
DBCC TRACEON (3604)
GO
–get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
DBCC PAGE (@dbName, 1, 9, 3);
GO
DBCC TRACEOFF (3604)
GO
GO
–get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
DBCC PAGE (@dbName, 1, 9, 3);
GO
DBCC TRACEOFF (3604)
GO
You can get the same information(dbi_version and dbi_createVersion) for the database from this DBCC command.
4.2 Get the values from a temp table
You can run another query to get the values in a table:
DBCC TRACEON (3604)
GO
CREATE TABLE #t (ParentObject VARCHAR (255), [Object] VARCHAR (255), Field VARCHAR (255), [Value] VARCHAR (255))
––get your database name
declare @dbName varchar(128)
Set @dbName=(select DB_name())
insert into #t
exec (‘DBCC PAGE(‘+@dbName+’,1,9,3) WITH TABLERESULTS’)
GO
select [dbi_dbname],[dbi_version],[dbi_createVersion] from (SELECT Field, Value FROM #t) src
PIVOT (Max(Value) For Field IN ([dbi_dbname],[dbi_version],[dbi_createVersion])) pvt
–select * from #t
drop table #t
DBCC TRACEOFF (3604)
GO
4.3 Get the values on the fly:
EXEC sp_configure ‘show advanced options’,1
GO
reconfigure
Go
EXEC sp_configure ‘Ad Hoc Distributed Queries’, 1
GO
reconfigure
GO
DBCC TRACEON (3604)
GO
declare @dbName varchar(128) = (select DB_name())
declare @cmd varchar(1000);
select @cmd = ‘SET FMTONLY OFF;SET NOCOUNT ON; EXEC(”” DBCC PAGE (‘+@dbName+’, 1,9,3) WITH TABLERESULTS””)';
EXEC(‘SELECT * INTO myVersion from OPENROWSET(”SQLNCLI”,”Server=USWDM2ML5054498\SQL08R2;Trusted_Connection=yes;”,”’ + @cmd + ”’) AS t;’ )
SELECT Field, Value FROM myVersion
WHERE Field =’dbi_createVersion’ or Field =’dbi_crdate’ or Field =’dbi_Version’ or Field =’dbi_dbname’
DROP TABLE myVersion;
DBCC TRACEOff (3604)
GO