Partager via


Working with the New SQL Server 2008 Data Types

One question we have heard a lot since releasing the SQL Server 2005 Driver for PHP is “Does the driver work with SQL Server 2008?” The short answer is “Yes!” However, because the driver relies on the SQL Server 2005 ODBC driver to handle low-level communications with the server, we have heard some follow up questions about how our driver works with the new data types that are available in SQL Server 2008. In this post, I will demonstrate how the SQL Server 2005 Driver for PHP interacts with these new data types. If you are not familiar with the new SQL Server 2008 data types, you can read an overview here: SQL Server 2008: New Data Types.

 

New Data Types Summary

Here’s a quick summary of the new data types in SQL Server 2008 (with links to more detailed explanations):

· date: A date.

· time: A time.

· datetimeoffset : A date that is combined with a time of a day that has time zone awareness and is based on a 24-hour clock.

· datetime2 : A date that is combined with a time of day that is based on 24-hour clock. This type that has a larger date range, a larger default fractional precision than the legacy datetime type, and it allows for optional user-specified precision.

· hierarchyid : A variable length, system data type used to represent position in a hierarchy.

· geometry : A .NET Common Language Runtime (CLR) data type that represents data in a Euclidean (flat) coordinate system.

· geography : A .NET common language runtime (CLR) data type that represents data in a round-earth coordinate system.

 

Retrieving New Data Types

You can retrieve any of the types mentioned above as strings. With the date, time, datetimeoffset, and datetime2 types, this happens by default when you retrieve these types with sqlsrv_fetch_array or the combination of sqlsrv_fetch/sqlsrv_get_field. Note that the legacy datetime and smalldatetime types are returned as PHP Datetime objects by default. We’d be interested in your feedback about the preferred default return types for the new data types, as well as the legacy types.

The process for retrieving the hierarchyid, geometry, and geography types as strings has a couple of twists, so let’s take a look at some examples. All the examples below are run against the NewTypesDB database; a SQL script that creates and populates this database is attached to this post. Also attached is a PHP script that contains the examples shown here, plus examples of how to retrieve the date, time, datetimeoffset, and datetime2 types.

To retrieve the geometry and geography types as strings, the .ToString() method must be called on each type in the Transact-SQL that defines the query. This method converts the data to the SQL Server nvarchar(max) data type, which the SQL Server 2005 Driver for PHP converts to a PHP stream by default. So, one option is to retrieve these types with sqlsrv_fetch_array, which will convert the streams to strings automatically:

Note: SQL Server does not return a column name by default when the .ToString() method is called on a column. In the query below, I have specified column names in the Transact-SQL.

$tsql = "SELECT myGeometry.ToString()AS geom,
myGeography.ToString() AS geog
FROM GeoTable";
$stmt = sqlsrv_query($conn, $tsql);

while($row = sqlsrv_fetch_array($stmt, SQLSRV_FETCH_ASSOC))
{
print("<pre>");
print_r($row);
print("</pre>");
}

 

 

 

Another option would be to retrieve these types with the combination of sqlsrv_fetch/sqlsrv_get_field and specify the PHP return type as a string:

$tsql = "SELECT myGeometry.ToString()AS geom,
myGeography.ToString() AS geog
FROM GeoTable";
$stmt = sqlsrv_query($conn, $tsql);

while(sqlsrv_fetch($stmt))
{
echo sqlsrv_get_field($stmt, 0,

          SQLSRV_PHPTYPE_STRING(SQLSRV_ENC_CHAR))."</br>";
echo sqlsrv_get_field($stmt, 1,

          SQLSRV_PHPTYPE_STRING(SQLSRV_ENC_CHAR))."</br>";
}

And, finally, a third option would be to retrieve these types as streams (the default):

$tsql = "SELECT myGeometry.ToString()AS geom,
myGeography.ToString() AS geog
FROM GeoTable";
$stmt = sqlsrv_query($conn, $tsql);

while(sqlsrv_fetch($stmt))
{
fpassthru(sqlsrv_get_field($stmt, 0));
echo "</br>";
}

Retrieving the hierarchyid type also requires calling the

.ToString() method on the type in the query, but this time the method returns a nvarchar(4000) data type. The SQL Server 2005 Driver for PHP returns this type as a string by default, so retrieving this type with sqlsrv_fetch_array or the combination of sqlsrv_fetch/sqlsrv_get_field should be straight forward. However, again note that SQL Server does not return a column name by default when the .ToString() method is called on the column:

Retrieving hierarchyid type using sqlsrv_fetch_array:

$tsql = "SELECT EmployeeName, Title,

                OrgNode.ToString() AS org
FROM HierarchyTable";
$stmt = sqlsrv_query($conn, $tsql);

 

while($row = sqlsrv_fetch_array($stmt, SQLSRV_FETCH_ASSOC))
{
print("<pre>");
print_r($row);
print("</pre>");
}

 

R

etrieving hierarchyid type using sqlsrv_fetch/sqlsrv_get_field:

$tsql = "SELECT EmployeeName, Title,

OrgNode.ToString() AS org
FROM HierarchyTable";
$stmt = sqlsrv_query($conn, $tsql);

while($row = sqlsrv_fetch_array($stmt, SQLSRV_FETCH_ASSOC))
{
echo sqlsrv_get_field($stmt, 0)."</br>";
echo sqlsrv_get_field($stmt, 1)."</br>";
echo sqlsrv_get_field($stmt, 2)."</br>";
}

Inserting New Data Types

With all of the new SQL Server 2008 data types you can simply send strings to the database. You will have to pay some attention to the format of the strings you send, but the server does a fairly good job of converting strings to the correct data type.

With the date, time, datetimeoffset, and datetime2 types, the format of the strings must be close to the expected format of the destination type. In some cases, however, the server will not be able to convert the supplied string to the desired data type (resulting in an error from the server).

In this example I send strings that closely match the format of the destination type:

$tsql = "INSERT INTO DateTimeTable (myDate,
myTime,
myDateTimeOffset,
myDatetime2)
VALUES (?, ?, ?, ?)";

 

$params = array(

            date("Y-m-d"), // Current date in Y-m-d format.
"15:30:41.987", // Time as a string.
date("c"), // Current date in ISO 8601 format.
date("Y-m-d H:i:s.u") // Current date and time.
);

$stmt = sqlsrv_query($conn, $tsql, $params);

With the geometry and geography types, strings must conform to the Open Geospatial Consortium (OGC) Well-Known Text (WKT) format. (For more information, see

Designing and Implementing Spatial Storage.) In the following example, I send POLYGON and LINESTRING data to the GeoTable:

$tsql = "INSERT INTO GeoTable (myGeometry,
myGeography)
VALUES (?, ?)";

$params = array(

'POLYGON ((0 0, 150 0, 150 150, 0 150, 0 0))',
'LINESTRING(-122.360 47.656, -122.343 47.656)'

);

$stmt = sqlsrv_query($conn, $tsql, $params);

And finally, the hierarchyid type can be sent to as a string as long as the string is a series of slashes separated by numerical values (e.g. /2/3/1/). The following code inserts an employee just below the CEO level (as a sibling to Sariya in the hierarchy defined in the HierarchyTable):

$tsql = "INSERT INTO HierarchyTable
(EmployeeName, Title, OrgNode)
VALUES (?, ?, ?)";

 

$params = array("Brian", "Specialist", "/2/");

$stmt = sqlsrv_query($conn, $tsql, $params);

That’s it. Please let me know if this has been useful/helpful. In my next post, I’ll address how to use the new filestream capabilities of SQL Server 2008 from PHP scripts.

Thanks.

Brian Swan

Programming Writer, SQL Server 2005 Driver for PHP

SQL 2008 Types Attachment.zip

Comments