Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Query Question Using Distinct concept in table joins Expand / Collapse
Author
Message
Posted Tuesday, January 28, 2014 10:45 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, October 28, 2014 11:44 AM
Points: 124, Visits: 103
Hi -

I have 4 tables that I need to join and return distinct results.

TableA is my main table and has 5 records.

Create TABLE [dbo].[TableA]
([ACTINDX] [int] NOT NULL,
[ACTNUMST] [char](129) NOT NULL)


SET ANSI_PADDING OFF
GO

Insert INTO TableA values ('1','000-100'), ('2', '000-200'), ('3', '000-300'), ('4', '000-400'), ('5', '000-500')

TableB - is similar to TableB - one-to-one relationship.

Create TABLE [dbo].[TableB]
([ACTINDX] [int] NOT NULL,
[ACTDESC] [char](129) NOT NULL)


SET ANSI_PADDING OFF
GO

Insert INTO TableB values ('1','CASH'), ('2', 'INVENTORY'), ('3', 'AR'), ('4', 'AP'), ('5', 'OVERHEAD')

Table C - is linked via ACTINDX - but may or may not have multiple values in it.

Create TABLE [dbo].[TableC]
([ACTINDX] [int] NOT NULL,
[CRDTAMNT] [numeric](19, 5) NOT NULL,
[DEBITAMT] [numeric](19, 5) NOT NULL)


SET ANSI_PADDING OFF
GO

Insert INTO TableC values ('1','100','0'), ('1','0','100'), ('1','100', '0'), ('2','300', '0'), ('2','0', '300'),
('2','100', '0'), ('2','0', '100'), ('4','100', '0'), ('4','0', '100')

TableD is similar to TableD - linked by ACTINDX and may or may not have single or multiple values in it.

Create TABLE [dbo].[TableD]
([ACTINDX] [int] NOT NULL,
[CRDTAMNT] [numeric](19, 5) NOT NULL,
[DEBITAMT] [numeric](19, 5) NOT NULL)


SET ANSI_PADDING OFF
GO

Insert INTO TableD values ('1','100','0'), ('1','0','100'), ('1','100', '0'), ('1','0', '100'), ('2','450', '0'), ('2','0', '450'),
('2','100', '0'), ('2','0', '100'), ('3','100', '0'), ('3','0', '100'), ('3', '50', '0'), ('3', '100', '0')


I'm trying to create a View that returns 5 records (one record for each record in TableA) as such:

ACTINDX ACTNUMST ACTDESC TransHistCurrent TransHistHistorical

1 000-100 CASH YES YES
2 000-200 INVENTORY YES YES
3 000-300 AR NO YES
4 000-400 AP YES NO
5 000-500 OVERHEAD NO NO

I created a View using this syntax:

Create view X_GLaccts_usage as
select TableA.ACTINDX as Actindex, TableA.ACTNUMST, TableB.ACTDESC,
(case when TableA.ACTINDX in (select DISTINCT ACTINDX from [TableC] ) then 'Yes' else 'No' end)
as 'TransHistCurrent',
(case when TableA.ACTINDX in (select DISTINCT ACTINDX from [TableD] ) then 'Yes' else 'No' end)
as 'TransHistHistorical'
from TableA
Left outer join TableC on TableC.ACTINDX = TableA.ACTINDX
Left outer join TableD on TableD.ACTINDX = TableA.ACTINDX
left outer join TableB on TableB.ACTINDX = TableA.ACTINDX

However, my view returns 35 records - basically my joins are incorrect - my case statements (maybe shouldn't use them?) seem to work - I'm just getting duplicate records

Any guidance would be appreciated..........

Post #1535561
Posted Tuesday, January 28, 2014 11:40 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: 2 days ago @ 2:05 PM
Points: 13,327, Visits: 12,820
Your sample data will not reproduce this issue. However, the reason you are getting "duplicate" rows is because in at least one of your additional tables your join matches on more than 1 row. Find one of the values from TableA that is returning multiple values then query each other table like this.

select count(*) from TableB where ACTINDX = [the value being duplicated]

I think you could greatly simplify your case expressions to.

case when TableC.ACTINDX IS NULL then 'No' else 'Yes' end as 'TransHistCurrent'



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1535571
Posted Tuesday, January 28, 2014 11:55 AM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Yesterday @ 3:35 PM
Points: 4,046, Visits: 9,202
The problem is that your JOINS are duplicating the rows because of the one-to-many relationship with tables C and D.
I'm leaving here 3 options that you might consider. On the first one, I just commented the joins and the problem was solved. The other 2 avoid the subqueries in the column list and use them in the FROM clause with JOIN or APPLY.
Be sure to understand the method you choose and if you have any questions, feel free to ask.

select a.ACTINDX as Actindex, 
a.ACTNUMST,
b.ACTDESC,
(case when a.ACTINDX in (select ACTINDX from #TableC ) then 'Yes' else 'No' end) as 'TransHistCurrent',
(case when a.ACTINDX in (select ACTINDX from #TableD ) then 'Yes' else 'No' end) as 'TransHistHistorical'
from #TableA a
--Left outer join #TableC c on c.ACTINDX = a.ACTINDX
--Left outer join #TableD d on d.ACTINDX = a.ACTINDX
left outer join #TableB b on b.ACTINDX = a.ACTINDX

SELECT a.ACTINDX as Actindex,
a.ACTNUMST,
b.ACTDESC,
case when c.ACTINDX IS NULL then 'No' else 'Yes' end as 'TransHistCurrent',
case when d.ACTINDX IS NULL then 'No' else 'Yes' end as 'TransHistHistorical'
FROM #TableA a
LEFT OUTER JOIN #TableB b on b.ACTINDX = a.ACTINDX
LEFT OUTER JOIN( SELECT ACTINDX FROM #TableC GROUP BY ACTINDX ) c ON c.ACTINDX = a.ACTINDX
LEFT OUTER JOIN( SELECT ACTINDX FROM #TableD GROUP BY ACTINDX ) d ON d.ACTINDX = a.ACTINDX

SELECT a.ACTINDX as Actindex,
a.ACTNUMST,
b.ACTDESC,
case when c.ACTINDX IS NULL then 'No' else 'Yes' end as 'TransHistCurrent',
case when d.ACTINDX IS NULL then 'No' else 'Yes' end as 'TransHistHistorical'
FROM #TableA a
LEFT OUTER JOIN #TableB b on b.ACTINDX = a.ACTINDX
OUTER APPLY( SELECT TOP 1 ACTINDX FROM #TableC c1 WHERE c1.ACTINDX = a.ACTINDX) c
OUTER APPLY( SELECT TOP 1 ACTINDX FROM #TableD d1 WHERE d1.ACTINDX = a.ACTINDX) d





Luis C.
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1535577
Posted Tuesday, January 28, 2014 12:36 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, October 28, 2014 11:44 AM
Points: 124, Visits: 103
Luis - Thank you so much.

I should have known that I didn't need to make the additional joins to the one-to-many relationships tables C and D.

I knew why I was getting duplicates and when you offered your solution - the light bulb went off.

Thanks again - everyone is great and helpful on this forum.

Have a great day - you earned it........
Post #1535585
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse