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


Trying to make my lookup table unique


Trying to make my lookup table unique

Author
Message
Oracle765
Oracle765
SSC-Addicted
SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)

Group: General Forum Members
Points: 418 Visits: 214
I am running the following query, what I am trying to do is only have in my reference table the first 3 unique columns, without loosing the other column values, I am not interested in the other columns being grouped but SqlSever is forcing me to group by them all with the following error. Msg 8120, Level 16, State 1, Line 6
Column 'lookuptable.Software_Subcategory' is invalid in the select list because it is not contained in either an aggregate function or the GROUP BY clause.

So I have had to group all columns

Any Ideas




drop table lookuptable1
select
Software_Name_Raw,
Software_Version_Raw,
Software_Publisher_Raw,
Software_Category,
Software_Subcategory,
MSDN_Flag,
CDL_Flag,
Source,
Pending_Classification_Flag,
Auto_Classification_Flag,
Software_Classification_Version,
Manual_Deletion,
Load_Date
into lookuptable1
from lookuptable
group by
Software_Name_Raw,
Software_Version_Raw,
Software_Publisher_Raw,
Software_Category,
Software_Subcategory,
MSDN_Flag,
CDL_Flag,
Source,
Pending_Classification_Flag,
Auto_Classification_Flag,
Software_Classification_Version,
Manual_Deletion,
Load_Date

AS YOU CAN SEE FROM MY RESULTS BELOW I ONLY NEED THE FIRST 3 COLUMNS BELOW for reference BUT I STILL NEED ALL THE DATA SO BASICALLY 1 OF THE ROWS COULD BE DELETED from the first 2 ROWS. as the first 3 columns match

select * from lookuptable1 where software_name_raw = 'Acrobat' order by software_name_raw

ACROBAT,6.X,Adobe Systems, Inc.,Licensable,Edition Unknown,FALSE,FALSE,TAD4D-Matched-DRN,No,Yes,0023,NULL,2012-09-08 16:41:38.000

ACROBAT,6.X,Adobe Systems, Inc.,Licensable,Edition Unknown,FALSE,FALSE,TAD5A-matched,DRN,No,Yes,0023,NULL,2012-09-08 16:41:38.000

ACROBAT,7.x,Adobe Systems, Inc.,Licensable,Edition Unknown,FALSE,FALSE,TAD4D-Matched-DRN,No,Yes,0023,NULL,2012-09-08 16:41:38.000
Jason-299789
Jason-299789
SSCarpal Tunnel
SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)

Group: General Forum Members
Points: 4657 Visits: 3232
I'm not sure what you are trying to do here.

The problem that you have is that on the first two rows you indicate for a required data set, the data in the Source column isn't the same, one has the value TAD4D-Matched, the other is TAD5A-Matched so they are not the same.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39120 Visits: 19990
Your requirement isn't totally clear Alan so I'll take a shot at interpretation and suggest ROW_NUMBER(), like this:

SELECT
rn = ROW_NUMBER() OVER (
PARTITION BY Software_Name_Raw, Software_Version_Raw, Software_Publisher_Raw
ORDER BY Load_Date),
Software_Name_Raw,
Software_Version_Raw,
Software_Publisher_Raw,
Software_Category,
Software_Subcategory,
MSDN_Flag,
CDL_Flag,
Source,
Pending_Classification_Flag,
Auto_Classification_Flag,
Software_Classification_Version,
Manual_Deletion,
Load_Date
FROM lookuptable



Run the code and examine the output. I'd guess you are interested in rows where rn=1.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
GilaMonster
GilaMonster
SSC Guru
SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)

Group: General Forum Members
Points: 210766 Visits: 46251
To be honest, that table looks like it needs normalising, looks like 3, maybe more tables in one.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Oracle765
Oracle765
SSC-Addicted
SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)

Group: General Forum Members
Points: 418 Visits: 214
hi guys sorry for the confusion, all i want to do is concentrate on the first 3 columns

so if the data shows this

Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,bla
Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,different bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,different bla
Sun Microsystems, Version 11.4.1,bla,bla,bla,bla

then i only want to remove the duplicate rows based on the first 3 columns being the same
so it should show
Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.4.1,bla,bla,bla,bla

ho[e this helps
marcel.eppel
marcel.eppel
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 50
Since you don't have a Identity column here you might have to use a row number to join the other columns back in.
Generally you could just split the information accordingly in your lookup tables and do it like this:

SELECT DISTINCT col1, col2, col3
INTO lookuptable1
FROM lookuptable



To prevent inserting duplicate rows you can also specify UNIQUE Constraints like this:

CREATE TABLE lookuptable1
( ID int IDENTITY(1,1) PRIMARY KEY
, col1 nvarchar(50)
, col2 nvarchar(50)
, col3 nvarchar(50)
CONSTRAINT [uqLookuptable1cols1_3] UNIQUE (col1, col2, col3)
)



Or if the table already exists:

ALTER TABLE lookuptable1 ADD CONSTRAINT [uqLookuptable1cols1_3] UNIQUE (col1, col2, col3)


ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39120 Visits: 19990
alan_lynch (3/5/2013)
hi guys sorry for the confusion, all i want to do is concentrate on the first 3 columns

so if the data shows this

Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,bla
Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,different bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,different bla
Sun Microsystems, Version 11.4.1,bla,bla,bla,bla

then i only want to remove the duplicate rows based on the first 3 columns being the same
so it should show
Adobe Inc,Version 1.3.1,Licensable,bla,bla,bla,bla
Sun Microsystems, Version 11.3.1,bla,bla,bla,bla
Sun Microsystems, Version 11.4.1,bla,bla,bla,bla

ho[e this helps


Did you run the code I posted above?

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
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