Union error due to field types

  • 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

  • If you change your UNION to a UNION ALL, it will work. Note that it will not filter out duplicates like UNION will.

  • Thanks but I need the duplicates filtered or it will make a mess of the results for some items.

  • 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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks sean

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

    How do I got about changing it in the query?

    Thanks

  • SELECT OptionCode, OptionDesc,

    OptionLongDesc = CAST(OptionLongDesc AS NVARCHAR(MAX)) , UnitPrice

    FROM tbMasterOption

    WHERE ...

  • 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.

  • 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!

  • 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

    . 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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • 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.

  • DaveK2014 (5/5/2014)


    That was it I didn't have it on the first section.

    Glad that worked for you!!

    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 best way to fix this is to normalize the data structures. I realize this is a third party app so you stuck but this violates 1NF by storing multiple datapoints in a single column. UGH!!!!!!!!!! Too bad you don't have the ability to fix this. Could you maybe add a computed column to the table?

    _______________________________________________________________

    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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • we are not able to add/subtract or anything. Got to work with what we got so this was the best way we could do it.

    It takes about 5 seconds to return so I think it should be ok. Thanks again for all your help.

Viewing 12 posts - 1 through 11 (of 11 total)

You must be logged in to reply to this topic. Login to reply