Columns that Contain a Null Value By Default
By default, a null value in a column maps to the absence of the attribute, node, or element. This default behavior can be overwritten by requesting element-centric XML using the ELEMENTS directive and specifying XSINIL to request adding elements for NULL values, as shown in the following query:
USE AdventureWorks2008R2;
GO
SELECT E.BusinessEntityID as "@EmpID",
FirstName as "EmpName/First",
MiddleName as "EmpName/Middle",
LastName as "EmpName/Last"
FROM HumanResources.Employee AS E
INNER JOIN Person.Person AS P
ON E.BusinessEntityID = P.BusinessEntitytID
WHERE E.EmployeeID=1
FOR XML PATH, ELEMENTS XSINIL;
The following shows the result. Note that if XSINIL is not specified, the <Middle> element will be absent.
<row xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" EmpID="1">
<EmpName>
<First>Ken</First>
<Middle xsi:nil="true" />
<Last>Sánchez</Last>
</EmpName>
</row>