13

I've been getting the error "Conversion failed when converting from a character string to uniqueidentifier" and am finally at the end of my rope. I've narrowed down my problem to as small as possible while keeping the error in tact. Install the CSV splitter from here first if you want to reproduce:

http://www.sqlservercentral.com/articles/Tally+Table/72993/

Here's the test code. I'm on SQL 2008R2 but in a database that is SQL 2005 compatible:

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[ZZZTESTTABLE]') AND type in (N'U'))
DROP TABLE [dbo].[ZZZTESTTABLE]
GO

CREATE TABLE [dbo].[ZZZTESTTABLE](
    [Col1] [uniqueidentifier] NOT NULL,
 CONSTRAINT [PK_ZZZTESTTABLE] PRIMARY KEY CLUSTERED 
(
    [Col1] ASC
)WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
) ON [PRIMARY]

-- Test table that I would like to check my values against
insert dbo.ZZZTESTTABLE(Col1) values('85B049B7-CDD0-4995-B582-5A74523039C0')

-- Test string that will be split into table in the DelimitedSplit8k function
declare @temp varchar(max) = '918E809E-EA7A-44B5-B230-776C42594D91,6F8DBB54-5159-4C22-9B0A-7842464360A5'

-- I'm trying to delete all data in the ZZZTESTTABLE that is not in my string but I get the error 
delete dbo.ZZZTESTTABLE
where Col1 not in 
(
-- ERROR OCCURS HERE
    select cast(Item as uniqueidentifier) from dbo.DelimitedSplit8K(@temp, ',')
)

HERE's the source for the DelimitedSplit8K function so you don't have to go and find it:

CREATE FUNCTION dbo.DelimitedSplit8K
--===== Define I/O parameters
        (@pString VARCHAR(8000), @pDelimiter CHAR(1))
RETURNS TABLE WITH SCHEMABINDING AS
 RETURN
--===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
     -- enough to cover VARCHAR(8000)
  WITH E1(N) AS (
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
                ),                          --10E+1 or 10 rows
       E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows
       E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max
 cteTally(N) AS (--==== This provides the "zero base" and limits the number of rows right up front
                     -- for both a performance gain and prevention of accidental "overruns"
                 SELECT 0 UNION ALL
                 SELECT TOP (DATALENGTH(ISNULL(@pString,1))) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4
                ),
cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)
                 SELECT t.N+1
                   FROM cteTally t
                  WHERE (SUBSTRING(@pString,t.N,1) = @pDelimiter OR t.N = 0) 
                )
--===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
 SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY s.N1),
        Item       = SUBSTRING(@pString,s.N1,ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000))
   FROM cteStart s
;
Skorpioh
  • 1,355
  • 1
  • 11
  • 30
  • I would suspect the split function since that's where the complexity is. If you add a WHERE Item is not null and LEN(Item) > 1 to the split select, does it still give an error? – hatchet - done with SOverflow Aug 08 '11 at 23:07
  • "I just found some random script on the internet, I don't understand how it works but I plan to use, can somebody debug it for me?" – Remus Rusanu Aug 08 '11 at 23:10
  • The split function seems ok. I also would like to know why your delete does not work as written. It fails the same way if rewritten as an EXISTS. – hatchet - done with SOverflow Aug 08 '11 at 23:57
  • 3
    Hey Remus, this isn't a random script and I've debugged with a good DBA already. I created the smallest example to reproduce the problem. Maybe you should look at it a little closer, seems like a SQL server bug. – creativejourney.com Aug 09 '11 at 00:07
  • 1
    I agree, and apology is needed. You did do your homework and this is indeed a problem that is not at all a simple coding issue, so I must apologize for what I said. I am following this up and investigating whether the UDF has some intrinsic procedural expectation (which QO is free to break) or is a truly pure declarative code and the generated execution plan is bad. – Remus Rusanu Aug 10 '11 at 05:06

4 Answers4

10

The use of this UDF is indeed making procedural assumptions about order of execution. It assumes that the WHERE clause inside the UDF will be evaluated before the cast(item as uniqueidentifier). This assumption is erroneous as the optimizer is free to change the plan to move the WHERE clause above the cast and the net effect is that the cast is asked to converts a partial token to a guid (ie. a string like 18E809E-EA7A-44B5-B230-776C42594D91).

For a more detailed answer read T-SQL functions do no imply a certain order of execution.

As a workaround you can force NULL into the projected values of the UDF for the rows that don't meet the WHERE clause:

CREATE FUNCTION dbo.DelimitedSplit8K
...
cteStart(N1, nullify) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)
                 SELECT t.N+1, 
                    case when (SUBSTRING(@pString,t.N,1) = @pDelimiter OR t.N = 0) then 1 else 0 end
                   FROM cteTally t
                  WHERE (SUBSTRING(@pString,t.N,1) = @pDelimiter OR t.N = 0) 
                )
--===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
 SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY s.N1),
        Item       = case s.nullify
            when 1 then SUBSTRING(@pString,s.N1,ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000))
            else null
            end
   FROM cteStart s;
go

Because the CASE expression is guaranteed to be evaluated before the CAST (since the input of the CAST is the output of the CASE) the reordering of the WHERE clause is safe.

Remus Rusanu
  • 288,378
  • 40
  • 442
  • 569
  • I sent you a LinkedIn message with a bad assumption because I misread your blog. Please disregard with my humble apologies. – Jeff Moden Feb 12 '14 at 08:03
5

Not sure what is happening here, but the problem does not appear to be the format of the guids or the output of the function. Executing this works:

declare @temp varchar(max) = '918E809E-EA7A-44B5-B230-776C42594D91,6F8DBB54-5159-4C22-9B0A-7842464360A5'    
select cast(Item as uniqueidentifier) from dbo.DelimitedSplit8K(@temp, ',')

Maybe the query processor is looking at the return schema of the function and saying that it can't be cast to uniqueidentifier? Hopefully someone else can provide a specific answer to that.

Selecting the output of the split function into a temp table will work:

select cast(Item as uniqueidentifier) as Item into #temp from dbo.DelimitedSplit8K(@temp, ',')

-- I'm trying to delete all data in the ZZZTESTTABLE that is not in my string but I get the error 
delete dbo.ZZZTESTTABLE
where Col1 not in 
(
-- ERROR OCCURS HERE
    --select cast(Item as uniqueidentifier) from dbo.DelimitedSplit8K(@temp, ',')
    select Item from #temp
)
Jeff Ogata
  • 56,645
  • 19
  • 114
  • 127
  • 1
    Thanks, that is one solution we came up with as well and probably the one we'll be using. Some things I noticed that it may be related to are: I can take the Select statement out of the where clause on its own and it works fine. I can also change the NOT IN to simply IN and I get no error (though I don't get the result I want). It does seem to be related to how the UDF (User Defined Function) returns or uses a CTE (Common Table Expression). If I change the UDF to return a hard coded string in a table, I won't get the error. I think a SQL bug or feature. Thanks much for looking into this!!! – creativejourney.com Aug 09 '11 at 00:12
2

Why cast Item to uniqueidentifier when you can do it the other way around.

Instead of

where Col1 not in 
(
-- ERROR OCCURS HERE
    select cast(Item as uniqueidentifier) from dbo.DelimitedSplit8K(@temp, ',')
)

you may try this:

where cast(Col1 as varchar(64)) not in 
(
    select Item 
    from dbo.DelimitedSplit8K(@temp, ',')
)
Skorpioh
  • 1,355
  • 1
  • 11
  • 30
  • if the split function is spitting out strings that can't be converted to uniqueidentifer, then it is mangling the strings somehow. Avoiding the CAST would remove the error, but the result would still not be correct (i.e. something would get deleted that shouldn't or vice versa). – hatchet - done with SOverflow Aug 08 '11 at 23:15
  • being an optimist, I just assumed that the function DelimitedSplit8K does it's job well. Testing that should be really simple, namely running SELECT * FROM dbo.DelimitedSplit8K('918E809E-EA7A-44B5-B230-776C42594D91,6F8DBB54-5159-4C22-9B0A-7842464360A5', ',') – Skorpioh Aug 08 '11 at 23:23
  • the split function does split the strings ok, and your solution does work around whatever oddness is causing the cast to fail in the original code. – hatchet - done with SOverflow Aug 08 '11 at 23:55
  • Sorry, it does work if I don't cast to GUID but use the other way around as specified. Of course, I didn't think of that because in theory, I wanted to be as specific as possible and it should have worked. Thanks for the help!! – creativejourney.com Aug 09 '11 at 00:16
1

Looks like I misread the question the first time. Good job producing a test script that reproduces the error. The following works for me:

delete dbo.ZZZTESTTABLE
WHERE Col1 in
(
    select Z.Col1
    from dbo.ZZZTESTTABLE Z
    LEFT JOIN dbo.DelimitedSplit8K(@temp, ',') S on S.Item = Z.Col1
    where S.Item is null
)
OPTION (force order)
RichardTheKiwi
  • 105,798
  • 26
  • 196
  • 262
  • They are all valid. I can take the Select statement out of the where clause on its own and it works fine. I can also change the NOT IN to simply IN and I get no error (though I don't get the result I want). It does seem to be related to how the UDF (User Defined Function) returns or uses a CTE (Common Table Expression). If I change the UDF to return a hard coded string, I won't get the error. Looks like either a SQL bug or feature. – creativejourney.com Aug 09 '11 at 00:11