November 6, 2012 at 5:01 am
In a POC project I was looking into the SQL Server 2012 feature of partially contained databases.
To my surprise I encountered an error where I didn't expect one.
The code hereafter is a simplified test-case.
Server Collation = Latin1_General_CI_AS
Collation on database test is the same.
Running the code when database test has CONTAINMENT = PARTIAL gives an error (see below)
Running the code when database test has CONTAINMENT = NONE doesn't give any error.
So it seems that there is some change in collation behavior depending on the CONTAINMENT type ...
USE [master]
GO
ALTER DATABASE [test] SET CONTAINMENT = PARTIAL WITH NO_WAIT -- WILL RESULT IN ERROR
-- ALTER DATABASE [test] SET CONTAINMENT = NONE WITH NO_WAIT -- WILL WORK
GO
USE [test]
GO
DROP TABLE TEST_CASE
GO
CREATE TABLE TEST_CASE
(namevarchar(10)NOT NULL
,CONSTRAINT PK_LOG_FILTER_PK PRIMARY KEY CLUSTERED (name)
)
GO
;
MERGE INTO TEST_CASETarget
USING(
SELECT'case'AS name
)Source
ON( Target.name = Source.name )
WHEN NOT MATCHED BY TARGETTHENINSERT ( name ) VALUES ( Source.name )
WHEN NOt MATCHED BY SOURCETHENDELETE
OUTPUT$action
,CASE
WHEN $action = 'INSERT' THEN 'ADDED'
WHEN $action = 'DELETE' THEN 'REMOVED'
END ACTION
,inserted.name
,deleted.name
;
Msg 468, Level 16, State 9, Line 12
Cannot resolve the collation conflict between "Latin1_General_CI_AS" and "Latin1_General_100_CI_AS_KS_WS_SC" in the equal to operation.
Can anyone give me a satisfactory explanation ...
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
November 13, 2012 at 3:17 am
Hi,
The only thing I can think of is replacing:
ON( Target.name = Source.name )
with
ON( Target.name COLLATE Latin1_General_CI_AS = Source.name COLLATE Latin1_General_CI_AS )
Hope this helps.
November 13, 2012 at 3:28 am
D.Post (11/13/2012)
Hi,The only thing I can think of is replacing:
ON( Target.name = Source.name )
with
ON( Target.name COLLATE Latin1_General_CI_AS = Source.name COLLATE Latin1_General_CI_AS )
Hope this helps.
Yes, and no š
First: I'm aware of the COLLATE clause to overcome differences in collating stuff.
Second: the error isn't on the JOIN condition, but on the CASE-part where I check the $action field.
So the COLLATE clause should go there.
CASE
WHEN $action = 'INSERT' THEN 'ADDED'
WHEN $action = 'DELETE' THEN 'REMOVED'
END ACTION
BUT: the question was rather why there is a difference in behavior between a PARTIALLY CONTAINED database and a NON-PARTIALLY CONTAINED database.
As far as I'm concerned: this is a bug š
I've got SQL Server Days coming up, and I'm going to relate this issue to some of the speakers.
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
November 13, 2012 at 6:26 am
Your code works for me on both
2008 (10.50.1600) Enterprise
2012 (10.0.2100) Evaluation
Both results are the same.
$actionACTIONnamename
INSERTADDEDcaseNULL
I can reproduce your error by forcing an incorrect collation:
CASE
WHEN $action COLLATE Latin1_General_CI_AS = 'INSERT' COLLATE SQL_Latin1_General_Cp437_BIN THEN 'ADDED'
WHEN $action = 'DELETE' THEN 'REMOVED'
END ACTION
Msg 468, Level 16, State 9, Line 12
Cannot resolve the collation conflict between "SQL_Latin1_General_CP437_BIN" and "Latin1_General_CI_AS" in the equal to operation.
November 13, 2012 at 6:47 am
Really appreciate you looking in/at this issue.
The fact that you can reproduce the error by adding the COLLATE-clause is "as designed" in SQL Server.
Forget the SQL 2008 track for now.
The code is working in a SQL 2008 environment.
The code also works in a SQL 2012 environment only when the database wherein you work has CONTAINMENT TYPE NONE
Did you have a try with the code against a database with CONTAINMENT TYPE PARTIAL ?
I also installed Service Pack I for SQL 2012, but the error still occurs
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
November 13, 2012 at 7:04 am
marc.snoeys (11/13/2012)
D.Post (11/13/2012)
CASE
WHEN $action = 'INSERT' THEN 'ADDED'
WHEN $action = 'DELETE' THEN 'REMOVED'
END ACTION
BUT: the question was rather why there is a difference in behavior between a PARTIALLY CONTAINED database and a NON-PARTIALLY CONTAINED database.
Here is one possible explanation as to what is going on:
In the contained database scenario $action is actually collated using the catalog default, i.e. Latin1_General_100_CI_AS_WS_KS_SC, per the table under the section Contained Databases in this article. Try adding COLLATE DATABASE_DEFAULT to collate $action in the CASE expression.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
November 13, 2012 at 7:08 am
With containment type partial I also get the error.
Can workaround with:
WHEN $action COLLATE SQL_Latin1_General_CP1_CI_AS = 'DELETE' THEN 'REMOVED'
I found these articles which might be of help :
November 14, 2012 at 3:42 am
opc.three (11/13/2012)
Here is one possible explanation as to what is going on:In the contained database scenario $action is actually collated using the catalog default, i.e. Latin1_General_100_CI_AS_WS_KS_SC, per the table under the section Contained Databases in this article. Try adding COLLATE DATABASE_DEFAULT to collate $action in the CASE expression.
It strikes me as very odd that changing the containment type of a database results in different behavior in code: in this case the $action field.
But this is just a personal opinion (however a few colleagues do agree)
I did a kind of an extension to this test-case:
- Database [test] in CONTAINMENT TYPE=NONE
- Create a stored procedure with the MERGE-statement above.
- Try to change the CONTAINMENT TYPE=PARTIAL
That resulted in following error, which is basically the same as in the first test-case.
Msg 468, Level 16, State 9, Procedure sp_TEST_CASE, Line 19
Cannot resolve the collation conflict between "Latin1_General_CI_AS" and "Latin1_General_100_CI_AS_KS_WS_SC" in the equal to operation.
Msg 12813, Level 16, State 2, Line 2
Errors were encountered in the procedure 'dbo.sp_TEST_CASE' during compilation of the object. Either the containment option of the database 'test' was changed, or this object was present in model db and the user tried to create a new contained database.
Msg 12836, Level 16, State 1, Line 2
ALTER DATABASE statement failed. The containment option of the database 'test' could not be altered because compilation errors were encountered during validation of SQL modules. See previous errors.
Msg 5069, Level 16, State 1, Line 2
ALTER DATABASE statement failed.
Apparently there is a view where one can query for possible problems when changing to a CONTAINED database: SYS.DM_DB_UNCONTAINED_ENTITIES
But a query on this view does not show this particular stored procedure.
All in all: I guess I'm forced to use the COLLATE-clause ...
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
November 14, 2012 at 5:23 pm
marc.snoeys (11/14/2012)
Apparently there is a view where one can query for possible problems when changing to a CONTAINED database: SYS.DM_DB_UNCONTAINED_ENTITIESBut a query on this view does not show this particular stored procedure.
I am not surprised. I would not expect the proc to be returned.
All in all: I guess I'm forced to use the COLLATE-clause ...
I think that is the correct move. Here is code that will be portable between both contained as well as non-contained databases regardless of which collation you are using in the database:
WHEN $action COLLATE DATABASE_DEFAULT = 'DELETE' THEN 'REMOVED'
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
November 28, 2012 at 3:40 am
A further update ...
I had a talk with Bob Beachemin about this issue ( and a few others stuff as well ).
He had a look at it and his conclusions were:
In fact, using any collation at random with the collate clause works, as long as you HAVE the collate clause
WHEN $action collate Albanian_BIN = 'INSERT' THEN 'ADDED'
WHEN $action collate Albanian_BIN = 'DELETE' THEN 'REMOVED'
So you can, as far as Iām concerned, report it as a contained database problem (the fact that you MUST do the collation sounds like a bug) AND/OR a documentation problem (there is no classification of $action anywhere in BOL). The behavior likely has to do with the rules for comparison predicates when collate clause is not specified, and the fact the $action is probably special cased somewhere in the (SQL Server) code.
So I decided to report it on CONNECT
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
December 7, 2012 at 12:34 am
Thanks for reporting the issue. The problem is due to the $action column metadata which is incompatible with the literal collation (string values 'INSERT' or 'DELETE'). This should work without requiring the collate clause. We will take a look at this.
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
December 7, 2012 at 10:09 am
nice follow-through! thanks for posting back
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
March 6, 2013 at 12:09 am
Yet another update on this issue:
Posted by Microsoft on 3/5/2013 at 11:50 AM
Hello Marc, We have now fixed this bug in the next major version of SQL Server. Thanks for reporting the issue. -- Umachandar, SQL Programmability Team
So, waiting for the "next major version" š
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
May 20, 2014 at 6:51 am
Let's revive this thread to acknowledge that the bug has been fixed within SQL SERVER 2014!
(or should I open a new thread in the proper subform š )
"Walking on water and developing software from a specification are easy if both are frozen." -- Edward V. Berard, "Life-Cycle Approaches"
October 18, 2015 at 11:40 pm
Hello,
Just to revive the thread once more, I am facing this issue in SQL 2014, and struggling with it. The only real difference is that this is not a table that I am struggling with, but a Stored Proc, so my error is...
Msg 468, Level 16, State 9, Procedure sp_PROC_NAME, Line 40
Cannot resolve the collation conflict between "Latin1_General_100_CI_AS_KS_WS_SC" and "Latin1_General_CI_AS" in the equal to operation.
Msg 12813, Level 16, State 2, Line 15
Errors were encountered in the procedure 'dbo.sp_PROC_NAME' during compilation of the object. Either the containment option of the database 'DATABASE_NAME' was changed, or this object was present in model db and the user tried to create a new contained database.
...looking what has previously been suggested in the thread, I'm having trouble putting two and two together. Can someone please help me with this? At this point I'm not sure if this issue was cleared up in 2014 or not. I'm running SQL 2014 SP1.
Thank you.
Regards,
D.
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply