SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Msg 468, Level 16, State 9, Procedure "procedurename", Line 129 Cannot resolve the collation...


Msg 468, Level 16, State 9, Procedure "procedurename", Line 129 Cannot resolve the collation conflict between "Latin1_General_CI_AS" and...

Author
Message
TomThomson
TomThomson
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14328 Visits: 12197
GOODS (9/19/2013)
Hi guys,

I'm have same issue:
Msg 468, Level 16, State 9, Procedure RPT_MTX_CDR_CostBreakdown_PerMsisdn, Line 142
Cannot resolve the collation conflict between "SQL_Latin1_General_CP1_CI_AS" and "Latin1_General_CI_AS" in the equal to operation.
I have the query below and my error massage is pointing at Line 142 and Line 142 is the SELECT DISTINCT.Please assist.

Select distinct ---------line 142
aa.Msisdn,
bb.box_no
into #MSISDNUnit
from #AllMSISDNCost aa
left join [10.24.4.56\EGHI].wasp_administration_SS.dbo.z_Unit_Lookup bb
on aa.MSISDN COLLATE DATABASE_DEFAULT = bb.MSISDN COLLATE DATABASE_DEFAULT
where bb.msisdn in (Select distinct msisdn from #AllMSISDNCost)
order by bb.box_no--24202

If you need to force the collation on the ON condition you also need to enforce it on the WHERE condition, as the columns involved are the same; so you could make it bb.MSISDN COLLATE DATABASE_DEFAULT in (Select distinct msisdn COLLATE DATABASE_DEFAULT from #AllMSISDNCost) .

Are you running with ANSI NULLs switched off, so that NULL in (select NULL) would deliver true?
Or are you working in a case sensitive system so that one (or both) of #AllMSISDNCost and z_Unit_Lookup has two columns, one called MSISDN and the other msisdn?

If neither of the above rather unusual things is true, do you think that filtering the result of left join on the equality condition by applying that where clause will produce something which would not be achieved by simplifying of the query to use an inner join and throwing away the where clause?

Tom

GOODS
GOODS
SSC-Enthusiastic
SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)

Group: General Forum Members
Points: 118 Visits: 253
Thanks it worked..
Amod Pusalkar
Amod Pusalkar
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 19
Hello,

I am looking for the resolution/clue for the error message I have been receiving since last 2-3 days.
Here is the scenario:

I have an .NET application where I am using SQL Server 2012 with Advanced Services x86 for database management. My development PCs have Windows 7 OS (one with 32-bit and other with 64-bit). The application is running as expected. I added one more PC with Windows 8 OS (64-bit) for testing purpose. I installed SQL Server 2012 with Advanced Services x64 on that PC. When I restored the database from Win7 pc to Win8 pc it got restored successfully in one go. On the database side, on both Win7 and Win8 pc, the database collation is set to the default type "SQL_Latin1_General_CP1_CI_AS"
Since past 2-3 days the application, when run on the Win8 pc, is giving me error for a particular stored procedure Cannot resolve the collation conflict between "SQL_Latin1_General_CP1_CI_AS" and "Latin1_General_CI_AS" in the equal to operation. It happens only on Win8 pc. I have not used any collation directives while using joins or comparing column values. I have already rechecked and reset the collation type on both the PCs but the error still persists on the win8 pc.
I am wondering why is this happening only on Win8 pc?
Could this issue be related with SQL Server version on Win8 pc? If yes, what could be the resolution to the issue?
Please share your valuable thoughts.
Thanks in advance.
TomThomson
TomThomson
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14328 Visits: 12197
Amod Pusalkar (12/20/2014)
Hello,

I am looking for the resolution/clue for the error message I have been receiving since last 2-3 days.
Here is the scenario:
.....
On the database side, on both Win7 and Win8 pc, the database collation is set to the default type "SQL_Latin1_General_CP1_CI_AS"

It's a very long time since any release of MS SQL Server has had that default. The default has been Latin1_General_CI_AS for at least 6 years, and I believe for quite a bit longer. Obvioulsy if you are working with MS SQL Server 2012 you must have set the instance default to SQL_Latin1_General_CP1_CI_AS on installation of one or more of your systems, and left it at the default on one or more.
The solution is first to find out what each instances default collation is. Then change the default collation of whatever instances can be changed with least trouble. You may also have to change column collations explicitly for any tables created with a column or columns using the instance default collation. If you are lucky the database schema designers will have explicitly declared collations for all character type columns so that that won't be necessary (you could still get errors with temp tables and maybe with sql local variables, so ).

Sometimes the easiest way to change the default collation for an instance is to uninstall it and reinstall with the correct default collation, but you need to be very careful that you don't lose any data if you do it that way. The alternative is the Rebuild Master utlity (if it still exists - I haven't used in recent versions of SQL Server) but some people find that harder than the other way even when they have lots of data to preserve.

Tom

Amod Pusalkar
Amod Pusalkar
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 19
TomThomson (12/20/2014)


It's a very long time since any release of MS SQL Server has had that default. The default has been Latin1_General_CI_AS for at least 6 years, and I believe for quite a bit longer. Obvioulsy if you are working with MS SQL Server 2012 you must have set the instance default to SQL_Latin1_General_CP1_CI_AS on installation of one or more of your systems, and left it at the default on one or more.
The solution is first to find out what each instances default collation is. Then change the default collation of whatever instances can be changed with least trouble. You may also have to change column collations explicitly for any tables created with a column or columns using the instance default collation. If you are lucky the database schema designers will have explicitly declared collations for all character type columns so that that won't be necessary (you could still get errors with temp tables and maybe with sql local variables, so ).

Sometimes the easiest way to change the default collation for an instance is to uninstall it and reinstall with the correct default collation, but you need to be very careful that you don't lose any data if you do it that way. The alternative is the Rebuild Master utlity (if it still exists - I haven't used in recent versions of SQL Server) but some people find that harder than the other way even when they have lots of data to preserve.


Hello Mr Tom,
Thanks for your quick reply.

While performing the installation of SQL Server 2012 Express on all afore-mentioned PCs I had kept the Collation type to whatever pre-filled value. I believe that value was "SQL_Latin1_General_CP1_CI_AS" so I thought it to be default for SQL Server. Also, I have checked the collation for model and tempdb databases and found that it was also "SQL_Latin1_General_CP1_CI_AS". There is no explicit collation specification for any column in any table hence it is "SQL_Latin1_General_CP1_CI_AS" for each column. If I am correct then the collation for database is preserved during the backup & restore activity and therefore on the destination server (if different than source) the server level collation and DB level collation can be different (I stand to be corrected by experienced members).
So in the mean while I am going to recheck all collation settings on each SQL instance once again.

--
Amod Pusalkar
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search