Most of datatypes is relative simple convert to a string.
For this we can use the CONVERT() or even the CAST() function:
- SELECT int_as_string = CONVERT(VARCHAR(20), int_field) FROM MyTable;
-
- SELECT int_as_string = CAST(int_field AS VARCHAR(20)) FROM MyTable;
But for some other datatypes convert is not so simple.
For example for MONEY, DATETIME, UNIQUEIDENTIFIER, BINARY, XML and TIMESTAMP datatypes.
There the script which shows how to convert such datatypes to strings:
- USE tempdb;
- GO
-
- -- Drop test table if exists
- IF OBJECT_ID('test_converts') IS NOT NULL
- DROP TABLE test_converts;
- GO
-
- -- Create test table
- -- The technique to generate random money value I have used from there:
- -- http://yabele.blogspot.de/2013/08/mssql-random-number-generator-with.html
- CREATE TABLE test_converts
- (
- mon MONEY NOT NULL DEFAULT RAND(CHECKSUM(NEWID())) * 1000,
- dt DATETIME NOT NULL DEFAULT GETDATE(),
- guid UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(),
- bin VARBINARY(MAX) NOT NULL DEFAULT NEWID(),
- x XML NOT NULL,
- ts TIMESTAMP
- );
- GO
-
- -- Fill test table with 3 records
- -- For all columns except "x" (xml) the default values will be used
- INSERT INTO test_converts (x)
- VALUES
- ('<a b="c"><d/></a>'),
- ('<e f="g"><h/></e>'),
- ('<i j="k"><l/></i>');
-
- -- Show original values
- SELECT * FROM test_converts;
-
- -- Convert values to string
- SELECT
- -- Third parameter (0) is default and generates result text
- -- in "0.00" format
- money_as_string = CONVERT(VARCHAR(20), mon, 0),
- -- Third parameter (121) generates result text
- -- in ODBC-canonical format: "yyyy-MM-dd HH:mm:ss.sss"
- datetime_as_string = CONVERT(VARCHAR(30), dt, 121),
- guid_as_string = CONVERT(VARCHAR(36), guid),
- -- Third parameter (1) generates result text
- -- in uppercase form with "0x" prefix
- binary_as_string = CONVERT(VARCHAR(MAX), bin, 1),
- xml_as_string = CONVERT(VARCHAR(MAX), x),
- timestamp_as_string = CONVERT(VARCHAR(MAX), CONVERT(VARBINARY(MAX), ts), 1)
- FROM
- test_converts;
After execution in SSMS (SQL Server Management Studio) we will have these two resultsets:
These techniques could be used for example to convert table-content to HTML.
In case you need convert values to HTML-string some converted string values will be necessary to HTML-encode:
- -- Convert values to HTML-string
- SELECT
- -- Third parameter (0) is default and generates result text
- -- in "0.00" format
- money_as_HTML = CONVERT(VARCHAR(20), mon, 0),
- -- Third parameter (121) generates result text
- -- in ODBC-canonical format: "yyyy-MM-dd HH:mm:ss.sss"
- datetime_as_HTML = CONVERT(VARCHAR(30), dt, 121),
- guid_as_HTML = CONVERT(VARCHAR(36), guid),
- -- Third parameter (1) generates result text
- -- in uppercase form with "0x" prefix
- binary_as_HTML = CONVERT(VARCHAR(MAX), bin, 1),
- -- Convert XML-string to HTML-encoded string
- xml_as_HTML = REPLACE(REPLACE(REPLACE(
- CONVERT(VARCHAR(MAX), x)
- , '&','&'), '<', '<'), '>', '>'),
- timestamp_as_HTML = CONVERT(VARCHAR(MAX), CONVERT(VARBINARY(MAX), ts), 1)
- FROM
- test_converts;
Correspondent resultset in SSMS:
See also:
MSSQL - The random number generator with a random initialization (random seed)