Monday, 3 August 2015

MSSQL - Convert speсial types to strings or HTML:
  • MONEY to string,
  • DATETIME to string,
  • GUID or UNIQUEIDENTIFIER to string,
  • VARBINARY or BINARY to string,
  • XML to string,
  • TIMESTAMP to string

Most of datatypes is relative simple convert to a string.
For this we can use the CONVERT() or even the CAST() function:
  1. SELECT int_as_string = CONVERT(VARCHAR(20), int_field) FROM MyTable;
  2.  
  3. 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:
  1. USE tempdb;
  2. GO
  3.  
  4. -- Drop test table if exists
  5. IF OBJECT_ID('test_converts') IS NOT NULL
  6. DROP TABLE test_converts;
  7. GO
  8.  
  9. -- Create test table
  10. -- The technique to generate random money value I have used from there:
  11. -- http://yabele.blogspot.de/2013/08/mssql-random-number-generator-with.html
  12. CREATE TABLE test_converts
  13. (
  14. mon MONEY NOT NULL DEFAULT RAND(CHECKSUM(NEWID())) * 1000,
  15. dt DATETIME NOT NULL DEFAULT GETDATE(),
  16. guid UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(),
  17. bin VARBINARY(MAX) NOT NULL DEFAULT NEWID(),
  18. x XML NOT NULL,
  19. ts TIMESTAMP
  20. );
  21. GO
  22.  
  23. -- Fill test table with 3 records
  24. -- For all columns except "x" (xml) the default values will be used
  25. INSERT INTO test_converts (x)
  26. VALUES
  27. ('<a b="c"><d/></a>'),
  28. ('<e f="g"><h/></e>'),
  29. ('<i j="k"><l/></i>');
  30.  
  31. -- Show original values
  32. SELECT * FROM test_converts;
  33.  
  34. -- Convert values to string
  35. SELECT
  36. -- Third parameter (0) is default and generates result text
  37. -- in "0.00" format
  38. money_as_string = CONVERT(VARCHAR(20), mon, 0),
  39. -- Third parameter (121) generates result text
  40. -- in ODBC-canonical format: "yyyy-MM-dd HH:mm:ss.sss"
  41. datetime_as_string = CONVERT(VARCHAR(30), dt, 121),
  42. guid_as_string = CONVERT(VARCHAR(36), guid),
  43. -- Third parameter (1) generates result text
  44. -- in uppercase form with "0x" prefix
  45. binary_as_string = CONVERT(VARCHAR(MAX), bin, 1),
  46. xml_as_string = CONVERT(VARCHAR(MAX), x),
  47. timestamp_as_string = CONVERT(VARCHAR(MAX), CONVERT(VARBINARY(MAX), ts), 1)
  48. FROM
  49. 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:
  1. -- Convert values to HTML-string
  2. SELECT
  3. -- Third parameter (0) is default and generates result text
  4. -- in "0.00" format
  5. money_as_HTML = CONVERT(VARCHAR(20), mon, 0),
  6. -- Third parameter (121) generates result text
  7. -- in ODBC-canonical format: "yyyy-MM-dd HH:mm:ss.sss"
  8. datetime_as_HTML = CONVERT(VARCHAR(30), dt, 121),
  9. guid_as_HTML = CONVERT(VARCHAR(36), guid),
  10. -- Third parameter (1) generates result text
  11. -- in uppercase form with "0x" prefix
  12. binary_as_HTML = CONVERT(VARCHAR(MAX), bin, 1),
  13. -- Convert XML-string to HTML-encoded string
  14. xml_as_HTML = REPLACE(REPLACE(REPLACE(
  15. CONVERT(VARCHAR(MAX), x)
  16. , '&','&amp;'), '<', '&lt;'), '>', '&gt;'),
  17. timestamp_as_HTML = CONVERT(VARCHAR(MAX), CONVERT(VARBINARY(MAX), ts), 1)
  18. FROM
  19. test_converts;

Correspondent resultset in SSMS:



See also:
MSSQL - The random number generator with a random initialization (random seed)

No comments:

Post a Comment

Note: only a member of this blog may post a comment.