January 19, 2018 at 12:34 pm
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.
January 19, 2018 at 2:58 pm
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
January 20, 2018 at 2:09 pm
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;
January 20, 2018 at 5:30 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.
January 21, 2018 at 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]
January 22, 2018 at 7:17 am
Paulo de Jesus - Sunday, January 21, 2018 7:38 AMI'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
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply