Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


DISTINCT in a SQL statements with a TEXT field


DISTINCT in a SQL statements with a TEXT field

Author
Message
Mark F-428640
Mark F-428640
SSC-Enthusiastic
SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)

Group: General Forum Members
Points: 182 Visits: 557
DISTINCT in a SQL statements with a TEXT field bombs.
Is there any work arounds out there?
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
Can you provide us with an example so that we can see what work-arounds might be applicable?

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
OK, I think I know what this one is...

Try this:


Select distinct CAST(TextCol as Varchar(MAX))



-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Mark F-428640
Mark F-428640
SSC-Enthusiastic
SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)

Group: General Forum Members
Points: 182 Visits: 557
Actually the code is -- select distinct * into table_remove_dups from table_A

so I have several fields and want to make sure all are unique with out duplicate values but one of my fields is a text field. Other than your suggestion to recast the data type (which is simular to me simply changing the datatype which I will do if there is no other way to do it) is there another way to check for the distinctness of this field with the others together? I don't really want to change the data type because I have chosen this data type as I believe that it is the largest character/string data type available to me and this field may become quite large.
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
This is the solution that you want to use. VARCHAR(MAX) can be as large as any TEXT datatype and is superior in virtually every respect. You can add all of the other columns onto this statement:

Select distinct Col1Name
, Col2Name
...
, CAST(TextColName as Varchar(MAX)) as [TextColName]
, ...
into table_remove_dups
from table_A



If you really want to keep the TEXT in the output (though I strongly encourage you to move to Varchar(MAX)), this this should work:

Select Col1Name
, Col2Name
...
, CAST(TextColName as TEXT) as [TextColName]
, ...
into table_remove_dups
from (Select distinct Col1Name
    , Col2Name
    ...
    , CAST(TextColName as Varchar(MAX)) as [TextColName]
    , ...
    from table_A) as A



-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Mark F-428640
Mark F-428640
SSC-Enthusiastic
SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)

Group: General Forum Members
Points: 182 Visits: 557
Thanks very much -- I didn't realize the Varchar(max) was the same size as Text column this in itself resolves my issue.
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
Thanks for the feedback, Mark.

Varchar(MAX) is one of the best things about SQL Server 2005, completely gets rid of the need for the BLOB's (Text, NText, etc.), meaning no more messy special functions and commands just to manipulate TEXT columns, no more mysterious failures that turn out to be because TEXT is not supported in that context (replication, etc.).

IMHO, this alone is reason enough to upgrade to SQL 2005.

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
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