Results 1 to 6 of 6
  1. #1
    Join Date
    Apr 2012
    Location
    Greenville, NC
    Posts
    3

    Question Unanswered: Duplicate Result Rows from 2 table join

    I am using SLQ Server 2008 R2. The database was designed by another company.

    I have two tables: Client and Client_Location. In the Client table the pk is Client_ID. There is also a unique key: sys_Client_ID. Both the Client_ID and the sys_Client_ID fields exist as a foreign keys in the Client_Location table. However, the fields are not noted as unique in the Client_Location table. There are two fields in the Client_Location table that determine when the address was effective. They are from_dt and end_dt.

    Multiple records have been loaded into the Client_Location table to track old as well as current addresses of clients.

    I'm trying to run a report that will pull clients with a plan_id constraint from the Client table and join the Client_Location table to retrieve the current address of these clients.
    My SQL is:

    select distinct (a.client_id), a.cli_last AS Last_Name,
    a.cli_first AS First_Name, a.cli_middle AS Mid_Init,
    b.city AS City, b.county AS County, b.state AS State
    from ECBH.dbo.tbl_Client a inner join ECBH.dbo.tbl_Client_Location b
    on a.client_id = b.client_id
    inner join ECBH.dbo.tbl_client_insurance c
    on a.client_id = c.client_id
    inner join ECBH_TEST.dbo.tbl_GEF_County d
    on b.county = d.COUNTY_NAME
    where c.plan_id = 4
    order by a.cli_last, a.cli_first

    Because multiple records exist in the Client_Location table, the result set has duplicates. How can I pull only the results where the from_dt is most recent?

  2. #2
    Join Date
    Apr 2012
    Posts
    213
    There are no rows with the same date (from_dt), try:

    Code:
    where (c.plan_id = 4) and 
          (b.from_dt = (select MAX(from_dt) from ECBH.dbo.tbl_Client_Location s
                             where s.client_id = b.client_id))
    Hope this helps.

  3. #3
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    personally, I would fix the data, but you can do this...


    select distinct (a.client_id), a.cli_last AS Last_Name,
    a.cli_first AS First_Name, a.cli_middle AS Mid_Init,
    b.city AS City, b.county AS County, b.state AS State
    from ECBH.dbo.tbl_Client a
    inner join
    (SELECT DISTINCT city,county,state,client_id
    FROM ECBH.dbo.tbl_Client_Location) b
    on a.client_id = b.client_id
    inner join ECBH.dbo.tbl_client_insurance c
    on a.client_id = c.client_id
    inner join ECBH_TEST.dbo.tbl_GEF_County d
    on b.county = d.COUNTY_NAME
    where c.plan_id = 4
    order by a.cli_last, a.cli_first
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  4. #4
    Join Date
    Apr 2012
    Location
    Greenville, NC
    Posts
    3

    Smile Answers to duplicate results

    Thank you both! I was able to adjust the code as suggested and had a perfect result set. I'm also grateful for this learning opportunity. Cheers!

  5. #5
    Join Date
    Feb 2004
    Location
    In front of the computer
    Posts
    15,579
    Provided Answers: 54
    With the schema design that you have, you really need to use slightly different logic. The problem is that with each row having a from and to date, you could have more than one valid location row at any point in time. I'd handle it like this:
    Code:
    SELECT DISTINCT a.client_id, a.cli_last AS Last_Name
    ,  a.cli_first AS First_Name, a.cli_middle AS Mid_Init
    ,  b.city AS City, b.county AS County, b.state AS State
       FROM ECBH.dbo.tbl_Client AS a
       INNER JOIN ECBH.dbo.tbl_Client_Location AS b 
          on a.client_id = b.client_id
          AND GetDate() BETWEEN b.from_dt and b.end_dt
       INNER JOIN ECBH.dbo.tbl_client_insurance AS c 
          ON a.client_id = c.client_id
       INNER JOIN ECBH_TEST.dbo.tbl_GEF_County d 
          ON b.county = d.COUNTY_NAME
       WHERE c.plan_id = 4
       ORDER BY a.cli_last, a.cli_first
    -PatP
    In theory, theory and practice are identical. In practice, theory and practice are unrelated.

  6. #6
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    I should actually read the whole post...
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

Tags for this Thread

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •