FILESTREAM Data Type

The new FILESTREAM data type in SQL Server 2008 offers a new way of storing unstructured data (images, documents, video, etc.). Up until now the two standard ways to store such data have been either in the database as BLOB objects or as files outside of the database. FILESTREAM provides the best of both worlds, storing unstructured data in the file system while maintaining transactional consistency with other structured data.

Here is a summary of the new capabilities offered by FILESTREAM:

• Implemented as VARBINARY(MAX)
• No limitation of 2 GB
• Stored in the file system
• Fast read access
• Good for objects larger than ~ 1 – 2 MB
• Encryption is not supported
• Setting to NULL deletes the BLOB data
• Transactional consistency
• Windows access via the OpenSqlFilestream APIs (read/write; no delete or rename)
• Uses Windows cache, not using SQL Server buffer pool, more memory for queries
• A ROWGUIDCOL column is required to use FILESTREAM data with Win32 APIs

Enabling FILESTREAM:

EXEC sp_filestream_configure

    @enable_level = 3,

    @share_name = "FileStreamShare";

Levels:

0 – Disabled. This is the default value
1 – Enabled only for Transact-SQL access
2 – Enabled only for Transact-SQL and local file system access
3 – Enabled for Transact-SQL, local file system access, and remote file system access

Creating database supporting FILESTREAM and table with FILESTREAM column:

CREATE DATABASE BlobDatabase ON PRIMARY

(NAME = Blob, FILENAME = 'C:DataBlob.mdf'),

FILEGROUP FSGroup CONTAINS FILESTREAM

(NAME = BlobFS, FILENAME = 'C:DataFileStream')

LOG ON ( NAME = BlobLog, FILENAME = 'C:DataBlob.ldf');

 

 

CREATE TABLE BlobDatabase.dbo.Images (

 image_id UNIQUEIDENTIFIER ROWGUIDCOL NOT NULL UNIQUE,

 image_desc VARCHAR(35),

 image_data VARBINARY(MAX) FILESTREAM NULL);

Update (August 20, 2008)

There have been some changes in the RTM version of SQL Server 2008. To enable FILESTREAM in the release version go to SQL Server Configuration Manager, open the Properties of the instance, on the FILESTREAM tab select Enable FILESTREAM for Transact-SQL access. Then open a query and execute the following:

EXEC sp_configure filestream_access_level, 2;

RECONFIGURE;

The stored procedure sp_filestream_configure used in the prerelease versions has been removed. Now the sp_configure procedure is used as demonstrated above. The new access level values are as follows:

0 – Disables FILESTREAM support for this instance (default)
1 – Enables FILESTREAM for Transact-SQL access
2 – Enables FILESTREAM for Transact-SQL and Win32 streaming access

In addition, one note from the field – turning off the 8.3 name generation on the NTFS volume using the command prompt utility fsutil helps a lot on performance.

Additional resources:

FILESTREAM Overview
http://msdn.microsoft.com/en-us/library/bb933993(SQL.100).aspx

Designing and Implementing FILESTREAM Storage
http://msdn.microsoft.com/en-us/library/bb895234(SQL.100).aspx

New Date and Time Data Types

SQL Server 2008 introduces enhancements to the existing date and time data types. The most important changes are the addition of separate DATE and TIME data types. The DATETIME2 data type adds more precision to the existing DATETIME data type, and DATETIMEOFFSET provides support for time zones. Here is a list of the new data types:

New data types:

• DATE (0001-01-01 through 9999-12-31)
• TIME (00:00:00.0000000 through 23:59:59.9999999)
• DATETIME2 (fraction 0 through 7)
• DATETIMEOFFSET (time zone awareness)

There are also a few new functions to support those new data types. Here is a list of the added date and time functions:

New functions:

• SYSDATETIME
• SYSDATETIMEOFFSET
• SYSUTCDATETIME
• SWITCHOFFSET
• TODATETIMEOFFSET

Follows a brief example to illustrate the use of the new date and time data types as well as the new functions.

-- The range for the DATE datatype is from 0001-01-01 through 9999-12-31

DECLARE @date DATE;

 

SET @date = CURRENT_TIMESTAMP;

 

PRINT @date;

 

-- The range for the TIME data type is 00:00:00.0000000 through 23:59:59.9999999

DECLARE @time TIME;

 

SET @time = CURRENT_TIMESTAMP;

 

PRINT @time;

 

-- Fraction 0 through 7

DECLARE @datetime2 DATETIME2(7);

 

SET @datetime2 = CURRENT_TIMESTAMP;

 

PRINT @datetime2;

 

SET @datetime2 = SYSDATETIME();

 

PRINT @datetime2;

 

-- Timezone offset range: -14:00 through +14:00

-- Date range: 0001-01-01 through 9999-12-31

-- Time range: 00:00:00 through 23:59:59.9999999

DECLARE @datetimeoffset DATETIMEOFFSET(7);

 

SET @datetimeoffset = CURRENT_TIMESTAMP;

 

PRINT @datetimeoffset;

 

SET @datetimeoffset = SYSDATETIMEOFFSET();

 

PRINT @datetimeoffset;

 

-- Functions

SELECT SYSDATETIME(),

       SYSDATETIMEOFFSET(),

       SYSUTCDATETIME(),

       CURRENT_TIMESTAMP,

       GETDATE(),

       GETUTCDATE();

 

-- New ISO week option for week number calculation      

SELECT DATEPART(ISO_WEEK, CURRENT_TIMESTAMP);   

 

-- Switch between time zones

SELECT SYSDATETIMEOFFSET(),

       SWITCHOFFSET(SYSDATETIMEOFFSET(), '+06:00'); --Paris

 

-- Set date and time offset based on DATETIME value

SELECT CURRENT_TIMESTAMP,

       TODATETIMEOFFSET(CURRENT_TIMESTAMP, '-01:00');

 

-- Convert DATETIME to DATE and TIME      

SELECT CONVERT(DATE, CURRENT_TIMESTAMP),

       CONVERT(TIME, CURRENT_TIMESTAMP);

Additional resources:

Using Date and Time Data
http://msdn.microsoft.com/en-us/library/ms180878(SQL.100).aspx

Date and Time Data Types and Functions
http://msdn.microsoft.com/en-us/library/ms186724(SQL.100).aspx

Hierarchies in SQL Server 2008

Graphs, tree algorithms and structures have been used for long time in databases to solve hierarchy related problems. Adjacency list, nested sets, materialized path, and other hybrid methods offer different capabilities to help.

SQL Server 2008 adds a new feature to help with modeling hierarchical relationships: the HIERARCHYID data type. It provides compact storage and convenient methods to manipulate hierarchies. In a way it is very much like optimized materialized path. In addition the SqlHierarchyId CLR data type is available for client applications.

While HIERARCHYID has a lot to offer in terms of operations with hierarchical data, it is important to understand a few basic concepts:

– HIERARCHYID can have only a single root (although easy to work around by adding sub-roots)
– It does not automatically represent a tree, the application has to define the relationships and enforce all rules
– The application needs to maintain the consistency

Here is a one example of employee hierarchy to illustrate the usage of HIERARCHYID and the related methods for manipulation of hierarchies.

CREATE TABLE Employees (

 emp_id INT NOT NULL PRIMARY KEY,

 emp_name VARCHAR(35),

 manager_id INT REFERENCES Employees(emp_id),

 org_chart_path HIERARCHYID);

 

/*

 

The primary key prevents cyclic paths.

Another way is using a CHECK constraint.

 

CHECK (org_chart_path.ToString() NOT LIKE '%/' + CAST(emp_id AS VARCHAR(10)) + '/_%')

 

*/

 

-- Insert the top level manager as hierarchy root

INSERT INTO Employees

VALUES (1, 'Jeff Brown', NULL, hierarchyid::GetRoot());

 

-- Insert John who reports to the top level manager                           

INSERT INTO Employees

VALUES (2, 'John Doe', 1,

           (SELECT hierarchyid::GetRoot().GetDescendant(NULL, NULL)

            FROM Employees));

 

 

-- Insert Peter at the same level as John

DECLARE @mgr HIERARCHYID = (SELECT org_chart_path

                            FROM Employees

                            WHERE emp_name = 'John Doe');

 

INSERT INTO Employees

VALUES (3, 'Peter Hanna', 1,

           (SELECT hierarchyid::GetRoot().GetDescendant(@mgr, NULL)

            FROM Employees

            WHERE org_chart_path = hierarchyid::GetRoot()));

 

-- Insert Richard as reporting to John

INSERT INTO Employees

VALUES (4, 'Richard Burns', 2,

           hierarchyid::Parse('/1/1/')); -- Also: CAST('/1/1/' AS HIERARCHYID)

 

SELECT emp_id, emp_name,

       manager_id, org_chart_path,

       org_chart_path.GetAncestor(1) AS emp_manager,

       hierarchyid::GetRoot() AS top_manager,

       org_chart_path.GetDescendant(NULL, NULL) AS emp_descendant,

       org_chart_path.GetLevel() AS emp_level,

       org_chart_path.ToString() AS emp_org_path

FROM Employees;

 

/*

 

emp_id emp_name         manager_id org_chart_path emp_manager   top_manager emp_descendant emp_level emp_org_path

------ ---------------- ----------- --------------- ------------- ------------ --------------- --------- ------------

1     Jeff Brown       NULL        0x             NULL         0x           0x58            0         /

2     John Doe         1           0x58            0x            0x           0x5AC0         1         /1/

3     Peter Hanna     1           0x68            0x            0x           0x6AC0         1         /2/

4     Richard Burns    2           0x5AC0         0x58         0x           0x5AD6         2         /1/1/

 

*/

 

-- Move Richard to report to Peter

DECLARE @new_mgr HIERARCHYID = (SELECT org_chart_path

                                FROM Employees

                                WHERE emp_name = 'Peter Hanna');

 

UPDATE Employees

SET org_chart_path = org_chart_path.Reparent(org_chart_path.GetAncestor(1),

                                            @new_mgr)

WHERE emp_name = 'Richard Burns';

 

SELECT emp_id, emp_name,

       manager_id, org_chart_path,

       org_chart_path.GetAncestor(1) AS emp_manager,

       hierarchyid::GetRoot() AS top_manager,

       org_chart_path.GetDescendant(NULL, NULL) AS emp_descendant,

       org_chart_path.GetLevel() AS emp_level,

       org_chart_path.ToString() AS emp_org_path

FROM Employees;   

 

/*

 

emp_id emp_name        manager_id org_chart_path    emp_manager   top_manager emp_descendant   emp_level emp_org_path

------- --------------- ----------- ----------------- ------------- ------------ ---------------- --------- ------------

1       Jeff Brown     NULL        0x                NULL         0x           0x58             0         /

2       John Doe        1           0x58             0x            0x           0x5AC0           1         /1/

3       Peter Hanna     1           0x68             0x            0x           0x6AC0           1         /2/

4       Richard Burns   2           0x6AC0            0x68         0x           0x6AD6           2         /2/1/

 

*/

From the above example it is very easy to see the similarity between materialized path and HIERARCHYID when the HIERARCHYID is converted to the character format using the ToString() method. Converting hierarchy from traditional parent/child format to HIERARCHYID is simple using recursive CTEs (very similar to building a materialized path).

Note:

This code has been tested with SQL Server 2008 CTP 6 (February 2008). As of SQL Server 2008 Release Candidate 0 (June 2008) the method Reparent() has been replaced with the method GetReparentedValue(). It is called using the same parameters and returns the same value.

Additional resources:

Using hierarchyid Data Types
http://msdn.microsoft.com/en-us/library/bb677173(SQL.100).aspx

Working with hierarchyid Data
http://msdn.microsoft.com/en-us/library/bb677212(SQL.100).aspx