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


Records common in both tables


Records common in both tables

Author
Message
curious_sqldba
curious_sqldba
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: 4727 Visits: 3691

panpk is identity value. I am trying to how many records (count) are common between both the tables. How do i do that?

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
Go

SELECT COUNT_Big( c.panpk )
FROM dbo.c_scope c
JOIN dbo.a_scope a
ON c.hfk = a.hfk
AND a.panpk = c.panpk


Eirikur Eiriksson
Eirikur Eiriksson
One Orange Chip
One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)

Group: General Forum Members
Points: 27715 Visits: 19169
curious_sqldba - Saturday, June 17, 2017 10:27 PM

panpk is identity value. I am trying to how many records (count) are common between both the tables. How do i do that?

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
Go

SELECT COUNT_Big( c.panpk )
FROM dbo.c_scope c
JOIN dbo.a_scope a
ON c.hfk = a.hfk
AND a.panpk = c.panpk


Quick question, why are you using TRANSACTION ISOLATION LEVEL READ UNCOMMITTED? The dirty read can easily produce incorrect results.
Cool

Here are some examples on how you can do this
USE TEEST;
GO
SET NOCOUNT ON;
IF OBJECT_ID(N'dbo.TBL_COMPARE_NUMBER') IS NOT NULL DROP TABLE dbo.TBL_COMPARE_NUMBER;
CREATE TABLE dbo.TBL_COMPARE_NUMBER
(
N INT NOT NULL PRIMARY KEY CLUSTERED
);

INSERT INTO dbo.TBL_COMPARE_NUMBER (N)
SELECT
NM.N
FROM dbo.TBL_NUMBERS NM
WHERE NM.N % 3 > 0;


INSERT INTO dbo.TBL_COMPARE_NUMBER (N)
SELECT
NM.N + 2000000
FROM dbo.TBL_NUMBERS NM
WHERE NM.N % 13 = 0;


-- #1
SELECT
COUNT(NM.N)
FROM dbo.TBL_COMPARE_NUMBER CN
INNER JOIN dbo.TBL_NUMBERS NM
ON NM.N = CN.N;

-- #2
SELECT
COUNT(CN.N)
FROM dbo.TBL_COMPARE_NUMBER CN
WHERE CN.N IN (SELECT NM.N FROM dbo.TBL_NUMBERS NM );

-- #3
SELECT
COUNT(CN.N)
FROM dbo.TBL_COMPARE_NUMBER CN
WHERE EXISTS (SELECT NM.N FROM dbo.TBL_NUMBERS NM
WHERE CN.N = NM.N);

-- #4
SELECT
COUNT(CN.N)
FROM dbo.TBL_COMPARE_NUMBER CN
LEFT OUTER JOIN dbo.TBL_NUMBERS NM
ON NM.N = CN.N
WHERE NM.N IS NOT NULL;

-- #5
SELECT
COUNT(CN.N)
FROM dbo.TBL_COMPARE_NUMBER CN
RIGHT OUTER JOIN dbo.TBL_NUMBERS NM
ON NM.N = CN.N
WHERE NM.N IS NOT NULL;


-- #6
SELECT
COUNT(NM.N)
FROM dbo.TBL_NUMBERS NM
CROSS APPLY dbo.TBL_COMPARE_NUMBER CN
WHERE CN.N = NM.N;

-- #7
SELECT
COUNT(CN.N)
FROM dbo.TBL_COMPARE_NUMBER CN
OUTER APPLY dbo.TBL_NUMBERS NM
WHERE CN.N = NM.N;




I get almost the same execution plan for all these queries so there shouldn't be any noticeable performance difference.

mhtanner
mhtanner
Valued Member
Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)Valued Member (73 reputation)

Group: General Forum Members
Points: 73 Visits: 132
If the tables have multiple columns and you want to count where all columns match


select count(*) from (
select * from dbo.c_scope
intersect
select * from dbo.a_scope
)x

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