Types don't match between the anchor and the recursive part in column "%.*ls" of recursive query "%.*ls".

Error Message:
Msg 240, Level 16, State 1, Line 1
Types don’t match between the anchor and the recursive part in column “%.*ls” of recursive query “%.*ls”.

Severity level:
16.

Description:
This error message appears when data types of a column in the anchor and the recursive part of a Common Table Expression are incompatible.

Consequences:
The T-SQL statement can be parsed, but causes the error at runtime.

Resolution:
Error of the Severity level 16 are generated by the user and can be fixed by the SQL Server user. The statement cannot be executed this way. The data types of the column must be compatible.

Versions:
This error message was introduced with SQL Server 2005.

Example(s):
USE tempdb;
GO
IF OBJECT_ID(‘tempdb..#t’) > 0
 DROP TABLE #t
GO
CREATE TABLE #t
(
 id INT,
 reportToID INT NULL,
)
INSERT INTO #t SELECT 1, NULL
UNION ALL SELECT 2, 1
UNION ALL SELECT 3, 1
UNION ALL SELECT 4, 2
GO
WITH MyCTE (id, reportToID, Level)
AS
(
 SELECT t1.ID, t1.reportToID, CAST(0 AS INT) AS Level
   FROM #t AS t1
  WHERE reportToID IS NULL
  UNION ALL
 SELECT t1.ID, t1.reportToID, CEILING(Level * RAND()) AS Level
   FROM #t AS t1
   JOIN MyCTE AS t2
     ON t1.reportToID = t2.ID
)
SELECT *
  FROM MyCTE
GO

Remarks:
In the above example the level column should be interpreted as column of type INTEGER. However, the RAND() function in the recursive part turns the expression into a non-compatible non-integer expression. This raises the error. To succesfully issue the batch, you must rephrase the CTE. For example:

USE tempdb;
GO
IF OBJECT_ID(‘tempdb..#t’) > 0
 DROP TABLE #t
GO
CREATE TABLE #t
(
 id INT,
 reportToID INT NULL,
)
INSERT INTO #t SELECT 1, NULL
UNION ALL SELECT 2, 1
UNION ALL SELECT 3, 1
UNION ALL SELECT 4, 2
GO
WITH MyCTE (id, reportToID, Level)
AS
(
 SELECT t1.ID, t1.reportToID, CAST(0 AS INT) AS Level
   FROM #t AS t1
  WHERE reportToID IS NULL
  UNION ALL
 SELECT t1.ID, t1.reportToID, CAST(CEILING(Level * RAND()) AS INT) AS Level
   FROM #t AS t1
   JOIN MyCTE AS t2
     ON t1.reportToID = t2.ID
)
SELECT *
  FROM MyCTE
GO

]]>

Leave a comment

Your email address will not be published.