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


Compare two rows in the same table for equality in SQL


Compare two rows in the same table for equality in SQL

Author
Message
sujeeth.selvam
sujeeth.selvam
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: 1

I have the following table in my database:

Table name: INSURANCE TABLE

Columns names: ID | Policy

Column Values:

1 | 34564
2 | 67548
3 | 34564
4 | 98271
5 | 90198
6 | 98271

I am looking for a sql query that will compare the Policy column values in all 5 rows and return those rows which have a value equal to atleast one other row.

For the table above I should get the following result set:

1 | 34564
3 | 34564

4 | 98271
6 | 98271

I would appreciate responses on how to write this query.


drew.allen
drew.allen
SSC-Forever
SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)

Group: General Forum Members
Points: 49793 Visits: 14720
There are a couple of ways that you can handle this depending on what you want to do with the results. Probably the most common is to use a CTE with a ROW_NUMBER to either filter out or delete the duplicate rows.

Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
pietlinden
pietlinden
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42732 Visits: 16085
Something like this:
CREATE TABLE Insurance (
RecordNo INT IDENTITY,
PolicyNo INT NOT NULL);
GO

INSERT INTO Insurance (PolicyNo)
VALUES (34564),(67548),(34564),(98271),(90198),(98271);


CTE to identify and delete duplicates (where ROW_NUMBER() > 1)
;WITH ctePolicyDupes(PolicyNo, dupeNumber)
AS
(SELECT i.PolicyNo
, ROW_NUMBER() OVER (PARTITION BY i.PolicyNo ORDER BY RecordNo) dupeNo
FROM Insurance i)
DELETE FROM ctePolicyDupes
WHERE dupeNumber>1;

Joe Celko
Joe Celko
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4259 Visits: 2916
[quote]
sujeeth.selvam - Friday, January 19, 2018 12:34 PM


>> have the following table in my database: <<

Where is the DDL for this table? What are the keys? What data types? What are the constraints? You really posted nothing. But worse than that, you seem to believe that there is such a thing as a generic, magical, universal "id" in RDBMS. There is not. We use keys and by definition, a key is a subset of the columns of a table such that they are unique for every row in that table. Guessing at what you might have meant to post, I would guess this:

CREATE TABLE Insurance_Policies
(foobar_id CHAR(2) NOT NULL PRIMARY KEY
CHECK(foobar_id LIKE '[0-9][0-9]'),
policy_nbr CHAR(5) NOT NULL
CHECK (policy_nbr LIKE '[0-9][0-9][0-9][0-9][0-9]')

INSERT INTO Insurance_Policies
VALUES
('01', '34564'),
('02', '67548'),
('03', '34564'),
('04', '98271'),
('05', '90198');
('06', '98271');

I am looking for a sql query that will compare the policy_nbr column values in all 5 rows and return those rows which have a value equal to at least one other row.

SELECT policy_nbr, MIN(foobar_id), MAX(foobar_id)
FROM Insurance_Policies
GROUP BY policy_nbr
HAVING COUNT(*) > 1;

I've made an assumption, since we don't have any specs, that there are only two duplicate foobar_id per policy number. This is one of the many many reasons that we ask people to post DDL. If I was correct you would've put constraints on your table to assure this.

Please post DDL and follow ANSI/ISO standards when asking for help.
Paulo de Jesus
Paulo de Jesus
SSC Eights!
SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)SSC Eights! (939 reputation)

Group: General Forum Members
Points: 939 Visits: 1398
I'm guessing this is what you are looking for:


WITH
Duplicates
AS
(
SELECT [Policy]
FROM Insurance
GROUP BY [Policy]
HAVING COUNT(ID) > 1
)

SELECT I.ID, I.[Policy]
FROM Insurance I
INNER JOIN
Duplicates D
ON D.[Policy] = I.[Policy]

drew.allen
drew.allen
SSC-Forever
SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)

Group: General Forum Members
Points: 49793 Visits: 14720
Paulo de Jesus - Sunday, January 21, 2018 7:38 AM
I'm guessing this is what you are looking for:


WITH
Duplicates
AS
(
SELECT [Policy]
FROM Insurance
GROUP BY [Policy]
HAVING COUNT(ID) > 1
)

SELECT I.ID, I.[Policy]
FROM Insurance I
INNER JOIN
Duplicates D
ON D.[Policy] = I.[Policy]

There's a more efficient way to handle this particular query. The original requires two scans of the table, once for the CTE and then once for the main query. The rewrite only requires one scan of the table.

WITH Duplicates AS
(
SELECT ID, [Policy], COUNT(*) OVER(PARTITION BY [Policy]) AS cnt
FROM Insurance
)

SELECT ID, [Policy]
FROM Duplicates
WHERE cnt > 1
;


Drew


J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
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