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


Union error due to field types


Union error due to field types

Author
Message
DaveK2014
DaveK2014
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 64
I am trying to run the query below. Between the %% will be certain text that we are looking for.

The problem is the union blows up because optionlongdesc is a ntext field. Any thoughts on how to make this work?

Thanks


select OptionCode, OptionDesc, OptionLongDesc, UnitPrice from tbMasterOption
where (RIGHT (OptionCode, 1) = 'E' or RIGHT (Optioncode,1) = 'U') and

OptionDesc like '%%' and
Optiondesc like '%%' and
OptionDesc like '%%'

union

select OptionCode, OptionDesc, OptionLongDesc, UnitPrice from tbMasterOption
where (RIGHT (OptionCode, 1) = 'E' or RIGHT (Optioncode,1) = 'U') and

OptionLongDesc like '%%' and
OptionLongDesc like '%%' and
OptionLongDesc like '%%'


order by OptionCode
stevenb 14609
stevenb 14609
Old Hand
Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)Old Hand (375 reputation)

Group: General Forum Members
Points: 375 Visits: 498
If you change your UNION to a UNION ALL, it will work. Note that it will not filter out duplicates like UNION will.
DaveK2014
DaveK2014
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 64
Thanks but I need the duplicates filtered or it will make a mess of the results for some items.
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25797 Visits: 17509
DaveK2014 (5/2/2014)

I am trying to run the query below. Between the %% will be certain text that we are looking for.

The problem is the union blows up because optionlongdesc is a ntext field. Any thoughts on how to make this work?

Thanks




Yes, change your table to use nvarchar(max) instead. the (n)text datatype has been deprecated. It is a pain to work with. You can't index it and you have to constantly convert it to a max datatype in order to use a where clause.

http://msdn.microsoft.com/en-us/library/ms187993.aspx

If you can't change the table you will have to do a convert in your query. You shouldn't have any issue changing the column to nvarchar(max) from ntext.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
DaveK2014
DaveK2014
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 64
Thanks sean

its a third party Database so I cant change it there.

How do I got about changing it in the query?

Thanks
Scott Coleman
Scott Coleman
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3784 Visits: 1463
SELECT  OptionCode, OptionDesc, 
OptionLongDesc = CAST(OptionLongDesc AS NVARCHAR(MAX)) , UnitPrice
FROM tbMasterOption
WHERE ...





DaveK2014
DaveK2014
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 64
Still get the same error

Msg 421, Level 16, State 1, Line 1
The ntext data type cannot be selected as DISTINCT because it is not comparable.
SQL is delicious
SQL is delicious
Valued Member
Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)

Group: General Forum Members
Points: 69 Visits: 174
DaveK2014 (5/2/2014)
Still get the same error

Msg 421, Level 16, State 1, Line 1
The ntext data type cannot be selected as DISTINCT because it is not comparable.


Very quick and dirty test...I created 2 test tables, 3 columns each; one had int, varchar(3), and ntext. The other had int, varchar(3), and nvarchar(max).

This worked to union them:



select col1,col2,cast(col3 as nvarchar(max)) as col3 from dbo.test1
union
select col1,col2,col3 from dbo.test2



I hope this helps!
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25797 Visits: 17509
Scott Coleman (5/2/2014)
SELECT  OptionCode, OptionDesc, 
OptionLongDesc = CAST(OptionLongDesc AS NVARCHAR(MAX)) , UnitPrice
FROM tbMasterOption
WHERE ...



Did you use the same cast in BOTH queries?


create table tbMasterOption
(
OptionCode nvarchar(10),
OptionDesc nvarchar(50),
OptionLongDesc ntext,
UnitPrice numeric(9, 2)
)

select OptionCode, OptionDesc, CAST(OptionLongDesc AS NVARCHAR(MAX)) as OptionLongDesc, UnitPrice from tbMasterOption
where (RIGHT (OptionCode, 1) = 'E' or RIGHT (Optioncode,1) = 'U') and

OptionDesc like '%%' and
Optiondesc like '%%' and
OptionDesc like '%%'

union

select OptionCode, OptionDesc, CAST(OptionLongDesc AS NVARCHAR(MAX)) as OptionLongDesc, UnitPrice from tbMasterOption
where (RIGHT (OptionCode, 1) = 'E' or RIGHT (Optioncode,1) = 'U') and

OptionLongDesc like '%%' and
OptionLongDesc like '%%' and
OptionLongDesc like '%%'


order by OptionCode



BTW, this query has some serious performance issue potentials. The first one is using a function on a column in your where predicate [RIGHT (OptionCode, 1)]. That is nonSARGable and will perform and index scan at best. The second issue is using leading wildcards for OptionDesc. The same issue of nonSARGability applies.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
DaveK2014
DaveK2014
Valued Member
Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)Valued Member (52 reputation)

Group: General Forum Members
Points: 52 Visits: 64
That was it I didn't have it on the first section.

I don't know of any other way to preform what I need to do other then those options.

I need the right as there are about 20,000 rows. The way it is setup is each item could have two prices based on what the customer selects. So if they pick level 1 they get price one, level 2 gets price 2. This is determined by the last letter of the option code. Any thoughts on that?

The wild card is to make it a bit easier for the user and not having to type out the everything.

It is a third party table so I don't to mess with anything and use full text index searching.
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