Finding Missing Inverse Relationships
Using EXCEPT
could help you write this query.
In short, if any rows of the first select do not have matches with the inverse + the correct RelType
& RelStatus
, return them.
SELECT PartyId , OtherPartyId, RelType , RelStatus
FROM dbo.Table
EXCEPT
SELECT OtherPartyId , PartyId, RelType , RelStatus
FROM dbo.Table;
DB<>Fiddle
Remember that if there are duplicate rows (E.G. 3 rows with an inverse relationship) these will not be returned.
Example
DDL
CREATE TABLE dbo.bla(ID INT IDENTITY(1,1) PRIMARY KEY NOT NULL,
PartyId int,
OtherPartyId int,
RelType int,
RelStatus int);
DML
INSERT INTO dbo.Bla(PartyId , OtherPartyId , RelType , RelStatus)
VALUES
(1111,2211 ,1 ,1),
(2211,1111 ,1 ,1),
(3344,4444 ,1 ,2),
(5555,2224 ,1 ,2),
(4444,3344 ,2 ,2),
(1111,2211 ,2 ,2);-- different type or status
Query
SELECT PartyId , OtherPartyId, RelType , RelStatus
FROM dbo.Bla
EXCEPT
SELECT OtherPartyId , PartyId, RelType , RelStatus
FROM dbo.Bla;
Result
PartyId OtherPartyId RelType RelStatus
1111 2211 2 2
3344 4444 1 2
4444 3344 2 2
5555 2224 1 2
Another solution could be using NOT EXISTS
, E.G. When you also need the Id
field.
SELECT Id,PartyId , OtherPartyId, RelType , RelStatus
FROM dbo.Bla b
WHERE NOT EXISTS
(
SELECT *
FROM dbo.Bla b2
where b.OtherPartyId = b2.PartyId
AND b.PartyId = b2.OtherPartyId
AND b.RelType = b2.RelType
AND b.RelStatus = b2.RelStatus
);
DB<>Fiddle
The most common version of the query to do this would be something like:
INSERT INTO PartyRelationships (
PartyId,
OtherPartyId,
RelType,
RelStatus
)
SELECT pr.OtherPartyID,
pr.PartyId,
pr.RelType,
pr.RelStatus
FROM papr
LEFT JOIN PartyRelationships pri
ON pr.PartyId = pri.OtherPartyId
AND pr.otherPartyId = pri.PartyId
AND pr.RelType = pri.RelType
AND pr.RelStatus = pri.RelStatus
WHERE pri.partyId is null
The EXCEPT example by @randi-vertongen is also a method to do this, and may be more efficient. And one other method that is not an example of the above is the MERGE method
MERGE INTO PartyRelationships AS pr
USING PartyRelationships AS pri
ON pr.PartyID = pri.OtherPartyId
AND pr.OtherPartyId = pri.PartyId
AND pr.RelType = pri.RelType
AND pr.RelStatus = RelStatus
WHEN NOT MATCHED THEN
INSERT(PartyId, OtherPartyId, RelType, RelStatus)
VALUES(pri.OtherPartyId, pri.PartyId, pri.RelType, pri.RelStatus);
This is basically the same as the first example, just using the MERGE syntax. However, this operation is a self-merge of a sort, so this makes logical sense to me.
Whichever option you choose will work for what you have requested.