Can you produce HTML from SQL? Yes, very easily. Would you ever want to? I certainly have had to. The principle is very simple. HTML is really just a slightly odd dialect of XML that imparts meaning to predefined tags. SQL Server has built-in ways of outputting a wide variety of XML. Although I’ve had in the past to output entire websites from SQL, the most natural thing is to produce HTML structures such as tables, lists and directories.
HTML5 can generally be worked on in SQL as if it were an XML fragment. XML, of course, has no predefined tags and is extensible, whereas HTML is designed to facilitate the rendering and display of data. By custom, it has become more forgiving than XML, but in general, HTML5 is based on XML.
Generating Tables from SQL expressions.
In HTML5, tables are best done simply, but using the child elements and structures so that the web designer has full control over the appearance of the table. CSS3 allows you to specify sets of cells within a list of child elements. Individual TD tags, for example, within a table row (TR) can delimit table cells that can have individual styling, but the rendering of the table structure is quite separate from the data itself.
The table starts with an optional caption element, followed by zero or more colgroup elements, followed optionally by a thead element. This header is then followed optionally by a tfoot element, followed by either zero or more tbody elements or one or more tr elements, followed optionally by a tfoot element, but there can be only one tfoot element.
The HTML5 ‘template’ for tables
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 |
<table> <caption></caption> <colgroup></colgroup>1..n <thead> <tr> <th></th>1..n </tr>1..n </thead> <tfoot> <tr> <td></td>1..n </tr>1..n </tfoot> <tbody> <tr> <td></td>1..n </tr>1..n </tbody>1..n </table> |
In SQL Server, one can create the XML for a table like this with this type of query which is in the form of a template with dummy data.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
SELECT (SELECT 'Table I' FOR XML PATH(''),TYPE) AS 'caption', (SELECT 'first' AS th, 'second' AS th FOR XML raw('tr'),ELEMENTS, TYPE) AS 'thead', (SELECT 'sum' AS th, 'twenty' AS th FOR XML raw('tr'),ELEMENTS, TYPE) AS 'tfoot', (SELECT F.unus AS td, F.duo AS td FROM (VALUES ('one', 'two'), ('three', 'four'), ('five', 'six'), ('seven', 'eight') ) F(unus, duo) FOR XML RAW('tr'), ELEMENTS, TYPE ) AS 'tbody' FOR XML PATH(''), ROOT('table') |
Which produces (after formatting it nicely) this
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 |
<table> <caption>Table I</caption> <thead> <tr> <th>first</th> <th>second</th> </tr> </thead> <tfoot> <tr> <th>sum</th> <th>twenty</th> </tr> </tfoot> <tbody> <tr> <td>one</td> <td>two</td> </tr> <tr> <td>three</td> <td>four</td> </tr> <tr> <td>five</td> <td>six</td> </tr> <tr> <td>seven</td> <td>eight</td> </tr> </tbody> </table> |
So, going to AdventureWorks, we can now produce a table that reports on the number of sales for each city, for the top thirty cities.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
SELECT CONVERT(NVARCHAR(MAX), (SELECT (SELECT 'Top Thirty Sales per City' FOR XML PATH(''), TYPE) AS 'caption', (SELECT 'Sales' AS th, 'City' AS th FOR XML RAW('tr'), ELEMENTS, TYPE) AS 'thead', ( SELECT TOP 30 COUNT(*) AS td, a.City + ', ' + sp.Name + ', ' + cr.Name AS td FROM Sales.SalesOrderHeader AS soh JOIN Person.Address AS a ON a.AddressID = soh.BillToAddressID JOIN Person.StateProvince AS sp ON sp.StateProvinceID = a.StateProvinceID JOIN Person.CountryRegion AS cr ON cr.CountryRegionCode = sp.CountryRegionCode GROUP BY a.City + ', ' + sp.Name + ', ' + cr.Name ORDER BY COUNT(*) DESC FOR XML RAW('tr'), ELEMENTS, TYPE ) AS 'tbody' FOR XML PATH(''), ROOT('table'))); |
I’ve left out the tfoot row because I didn’t need that. Likewise colgroup. I use tfoots mostly for aggregate lines, but you are limited to one only at the end, so it is not ideal for anything other than a simple ‘bottom line’.
When this is placed within and html file, with suitable CSS, it can look something like this
This is fine for general purposes, but there often comes a time when you need to highlight particular cells, based on an attribute from the data or a value. We can add, for example, class attributes, or anything else you need but you sacrifice the simplicity of FOR XML RAW. You will need to use FOR XML PATH, I reckon. This allows you to specify attributes (necessary for images and links) . However, because you are specifying the path in the AS clause, all your contiguous TD names will all get concatenated into one TD element unless you use a hack to indicate that they are separate. This is easier demonstrated than explained.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 |
SELECT CONVERT(NVARCHAR(MAX), (SELECT (SELECT 'Top Thirty Sales per City (' +CONVERT(CHAR(11),GETDATE(),113) +')' FOR XML PATH(''), TYPE) AS 'caption', (SELECT 'rank' AS th, 'Sales' AS th, 'City' AS th FOR XML RAW('tr'), ELEMENTS, TYPE) AS 'thead', ( SELECT TOP 30 CASE WHEN COUNT(*)>400 THEN 'TextRed' WHEN COUNT(*)>250 THEN 'TextMauve' ELSE 'TextBlue'END AS [td/@class], RANK() OVER (ORDER BY COUNT(*) desc) AS td , '' AS [*],--hack to allow the use of PATH COUNT(*) AS td,--PATH otherwise concatenates TDs '' AS [*],--hack to allow the use of PATH a.City + ', ' + sp.Name + ', ' + cr.Name AS td FROM Sales.SalesOrderHeader AS soh JOIN Person.Address AS a ON a.AddressID = soh.BillToAddressID JOIN Person.StateProvince AS sp ON sp.StateProvinceID = a.StateProvinceID JOIN Person.CountryRegion AS cr ON cr.CountryRegionCode = sp.CountryRegionCode GROUP BY a.City + ', ' + sp.Name + ', ' + cr.Name ORDER BY COUNT(*) DESC FOR XML PATH('tr'), ELEMENTS, TYPE ) AS 'tbody' FOR XML PATH(''), ROOT('table'))); |
Yes, we have altered the previous SQL to create ‘class’ attributes that have allowed us to colour the rank order numbers we’ve just added so that the best performers are in red, the next best in mauve and the rest in dark blue; first column only. It will look something like this…
Obviously, you can use this for any HTML tag that requires attribute. An image IMG tag needs its ‘src‘, for example, and the anchor A tag needs its ‘href‘. The only downside is that you lose the neatness of using RAW. HTML mixes attributes and elements so I suspect that you will need to use the FOR XML PATH syntax for this sort of work.
Generating directory lists from SQL expressions.
The HTML is for rendering name-value groups such as dictionaries, indexes, definitions, questions and answers and lexicons. The name-value group consists of one or more names (dt elements) followed by one or more values (dd elements). Within a single dl element, there should not be more than one dt element for each name.
We’ll take as an example an excerpt from the excellent SQL Server glossary
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 |
SELECT F.Term AS DT, F.Definition AS DD FROM ( VALUES ('cache aging', 'The mechanism of caching that determines when a cache row is outdated and must be refreshed' ), ('cache client', 'A .NET application that uses the Windows Server AppFabric client APIs to communicate with and store data to a Windows Server AppFabric distributed cache system.' ), ('cache cluster', 'The instantiation of the distributed cache service, made up of one or more instances of the cache host service working together to store and distribute data. Data is stored in memory to minimize response times for data requests. This clustering technology differs from Windows Clustering.' ), ('cache invalidation', 'The process of flagging an object in the cache so that it will no longer be used by any cache clients. This occurs when an object remains in cache longer than the cache time-out value (when it expires).' ), ('cache item', 'An object that is stored in the cache and additional information associated with that object, such as tags and version. It can be extracted from the cache cluster using the GetCacheItem client API.' ), ('cache notification', 'An asynchronous notification that can be triggered by a variety of cache operations on the cache cluster. Cache notifications can be used to invoke application methods or automatically invalidate locally cached objects.' ), ('cache operation', 'An event that occurs on regions or cached items that can trigger a cache notification.' ), ('cache port', 'A TCP/IP port used by cache hosts to transmit data to and from the cache clients. The port number used for the cache port can be different on each cache host. These settings are maintained in the cluster configuration settings.' ), ('cache region', 'A container of data, within a cache, that co-locates all cached objects on a single cache host. Cache Regions enable the ability to search all cached objects in the region by using descriptive strings, called tags.' ), ('cache service', 'The distributed, in-memory caching solution that enables users to build highly scalable and responsive applications by bringing data closer to end users.' ), ('cache tag', 'One or more optional string-based identifiers that can be associated with each cached object stored in a region. Regions allow you to retrieve cached objects based on one or more tags.' ), ('cache-aside programming pattern', 'A programming pattern in which if the data is not present in the cache, the application, not the distributed cache system, must reload data into the cache from the original data source.' ), ('cache-enabled application', 'An application that uses the Windows Server AppFabric cache client to store data in cache on the cache cluster.' ) ) F(Term, Definition) FOR XML RAW(''),ROOT('DL'), ELEMENTS, TYPE; |
This produces a directory list which can be rendered as you wish
Generating hierarchical lists from SQL expressions.
HTML Lists represent probably the most useful way of passing simple hierarchical data to an application. You can actually use directories (DLs) to do this for lists name-value pairs and even tables for more complex data. Here is a simple example of a hierarchical list, generated from AdventureWorks. You’d want to use a recursive function for anything more complicated. I’ll show you this in a moment. Here is a simple version that just gives you one level
1 2 3 4 5 6 7 8 9 10 11 12 |
SELECT CONVERT( NVARCHAR(MAX), (SELECT f.[Group] AS li, (SELECT g.Name AS li FROM Sales.SalesTerritory g WHERE g.[Group] = f.[Group] FOR XML RAW(''), ROOT('ul'), ELEMENTS, TYPE ) FROM Sales.SalesTerritory f GROUP BY f.[Group] FOR XML RAW(''), ROOT('ul'), ELEMENTS, TYPE ) ); |
…giving…
There is a more complex hierarchy in AdventureWorks that we can use to show how a hierarchy with arbitrary depth can be rendered as a list. Here is how you could do it. Firstly the recursive function
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
CREATE FUNCTION MeAndMyReports(@Me HIERARCHYID) RETURNS XML BEGIN RETURN (SELECT me.LoginID AS li, (SELECT dbo.MeAndMyReports(reports.OrganizationNode) FROM HumanResources.Employee AS reports WHERE reports.OrganizationNode.GetAncestor(1) = me.OrganizationNode FOR XML RAW(''), ROOT('ul'), ELEMENTS, TYPE ) FROM HumanResources.Employee AS me WHERE me.OrganizationNode = @Me FOR XML RAW(''), ELEMENTS, TYPE ); END; GO |
Now we can simply demonstrate how to call it….
1 2 3 4 5 6 7 |
DECLARE @boss HIERARCHYID; SELECT @boss = OrganizationNode FROM HumanResources.Employee WHERE Employee.LoginID = 'adventure-works\roberto0'; SELECT dbo.MeAndMyReports(@boss); |
and this will give you the list that then just needs the base <UL> node
Conclusions
There are quite a few structures now in HTML5. Even the body tag has subordinate header, nav, section, article, aside, footer, details and summary tags. If you read the W3C Recommendation it bristles with good suggestions for using markup to create structures. The pre tag can use child code, samp and kbd tags to create intelligent formatting. Data in SQL Server can easily generate this sort of structured HTML5 markup. This has obvious uses in indexes, chaptering, glossaries as well as the obvious generation of table-based reports. There is quite a lot of mileage in creating HTML from SQL Server queries
Load comments