6

I need to select the count of unique value combinations of column B in an XRef table which is grouped by column A.

Consider the following schema and data, which represents a simple family structure. Each child has a father and mother:

TABLE Father

FatherID Name
1 Alex
2 Bob

TABLE Mother

MotherID Name
1 Alice
2 Barbara

TABLE Child

ChildID FatherID MotherID Name
1 1 (Alex) 1 (Alice) Adam
2 1 (Alex) 1 (Alice) Billy
3 1 (Alex) 2 (Barbara) Celine
4 2 (Bob) 2 (Barbara) Derek

The distinct combinations of mothers for each father are:

  • Alex (Alice, Barbara)
  • Bob (Barbara)

In all there are two distinct combinations of mothers:

  1. Alice, Barbara
  2. Barbara

The query I want to write would return the count of those distinct combinations of mother, regardless of which father they are associated with:

UniqueMotherGroups
2

I was able to do this successfully using the STRING_AGG function, but it feels clunky. It also needs to operate over millions of rows and is quite slow at the moment. Is there a more idiomatic way to do this with set operations instead?

Here is my working example:

-- Drop pre-existing tables

DROP TABLE IF EXISTS dbo.Child;

DROP TABLE IF EXISTS dbo.Father;

DROP TABLE IF EXISTS dbo.Mother;

-- Create family tables.

CREATE TABLE dbo.Father
(
    FatherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Father
ADD CONSTRAINT PK_Father
    PRIMARY KEY CLUSTERED (FatherID);

ALTER TABLE dbo.Father SET (LOCK_ESCALATION = TABLE);

CREATE TABLE dbo.Mother
(
    MotherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Mother
ADD CONSTRAINT PK_Mother
    PRIMARY KEY CLUSTERED (MotherID);

ALTER TABLE dbo.Mother SET (LOCK_ESCALATION = TABLE);

CREATE TABLE dbo.Child
(
    ChildID INT NOT NULL
  , FatherID INT NOT NULL
  , MotherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Child
ADD CONSTRAINT PK_Child
    PRIMARY KEY CLUSTERED (ChildID);

CREATE NONCLUSTERED INDEX IX_Parents ON dbo.Child (FatherID, MotherID);

ALTER TABLE dbo.Child
ADD CONSTRAINT FK_Child_Father
    FOREIGN KEY (FatherID)
    REFERENCES dbo.Father (FatherID);

ALTER TABLE dbo.Child
ADD CONSTRAINT FK_Child_Mother
    FOREIGN KEY (MotherID)
    REFERENCES dbo.Mother (MotherID);

-- Insert two children with the same parents

INSERT INTO dbo.Father
(
    FatherID
  , Name
)
VALUES
(1, 'Alex')
, (2, 'Bob')
, (3, 'Charlie')

INSERT INTO dbo.Mother
(
    MotherID
  , Name
)
VALUES
(1, 'Alice')
, (2, 'Barbara');

INSERT INTO dbo.Child
(
    ChildID
  , FatherID
  , MotherID
  , Name
)
VALUES
(1, 1, 1, 'Adam')
, (2, 1, 1, 'Billy')
, (3, 1, 2, 'Celine')
, (4, 2, 2, 'Derek')
, (5, 3, 1, 'Eric');

-- CTE Gets distinct combinations of parents
WITH distinctParentCombinations (FatherID, MotherID)
AS (SELECT children.FatherID
         , children.MotherID
    FROM dbo.Child as children
    GROUP BY children.FatherID
           , children.MotherID
   )
   -- CTE Gets uses STRING_AGG to get unique combinations of mothers.
   , motherGroups (Mothers)
AS (SELECT STRING_AGG(CONVERT(VARCHAR(MAX), distinctParentCombinations.MotherID), '-') WITHIN GROUP (ORDER BY distinctParentCombinations.MotherID) AS Mothers
    FROM distinctParentCombinations
    GROUP BY distinctParentCombinations.FatherID
   )

-- Remove the COUNT function to see the actual combinations
SELECT COUNT(motherGroups.Mothers) AS UniqueMotherGroups
FROM motherGroups


-- Clean up the example

DROP TABLE IF EXISTS dbo.Child;

DROP TABLE IF EXISTS dbo.Father;

DROP TABLE IF EXISTS dbo.Mother;
bopapa_1979
  • 8,949
  • 10
  • 51
  • 76
  • What indexes exist on the tables? Have you looked at the _actual execution plan_ to see where the resources are going? You can use [paste the plan](https://www.brentozar.com/pastetheplan/instructions/) to include an execution plan in your question. – HABO Dec 02 '22 at 03:24

6 Answers6

2

You have a great explanation and setup of your "problem case". Your setup runs great in (for example) tempdb.

You have solved the problem in a nice way, and I don't think you can optimize it much further if you are going to calculate the mother groups every time you run the query.
There is one small mistake though; You must do a COUNT(DISTINCT motherGroups.Mothers) in your final count.

Since you mention milions of rows, I would suggest a slightly different approach. If you aggregate the mother groups as soon as there is a change in the Child table, your query can run fast every time - even with millions of rows. The kind of queries you want to run is seldom run only once, so it would be nice if the heavy work is already done.

Usually I prefer not to use triggers, because you get extra logic in a place where it could be hard to find and debug. But sometimes triggers are nice to have, especially when you are not able to change the source code running on the clients.

So, my solution is to add a new column to the Father table and to create a trigger which (re)generates the mother group each time there is a change in the Child table. This way, the hard aggregation work for each father is done as soon there is a change, and you don't have to aggregate when you run your query. Since you already have millions of rows, we also have to update these existing rows.
I have used SQL Server 2019 for this solution.

*** The solution ***
Add 1 or 2 new columns to the Father table. If you should add 1 or 2, it depends on what your preferences are: "Do I want to see the aggregated mother groups for debugging purpose, or do I just trust the hashed values?"

Column 1: Hashed value of the aggregated mother group for each Father row.
The hashed value is VARBINARY and is at least 32 bytes, but we will use VARBINARY(1600):

  1. 1600 is less than 1700 which is the max nonclustered index size, so we will not have any problems indexing the column.
  2. Since the hash value is in blocks of 32 bytes, a value of 1600 will cover a really, really, really long aggreated mother group.
-- Column 1: Hashed value of the aggregated mother group for each Father row.
alter table Father add MotherHash varbinary(1600)
create index IX_MotherHash on Father(MotherHash) 

Column 2: This column is more optional, and depends on your preferences. The column could be nice to have for debugging purpose if any questions are made about the result.
Which VARCHAR-length you should use depends on your real data.

  • MAX? Then you have no problems storing the mother groups, but you might have problems indexing it, since 1700 is the max for an unclustered index. But maybe you don't need to index it?
  • 1700? Then you are able to index the column, but depending on your real data, will this cover the biggest mother group?

Why indexing? If you want to list the aggregated mother groups, it could be faster to read the index than the whole table.
As said; this depends on you (and your data). If we have no need to see the aggregated mother groups, then we don't need this column at all.
For this demo/solution we will add the column for debugging purpose, without any indexing.

-- Column 2: This column is more optional, and depends on your preferences.
alter table Father add MotherGroup varchar(MAX)
go

Create a trigger on the Child table.
It will handle all inserts, updates and deletes in the Child table.

create or alter trigger trIUD_Child on Child
after insert, update, delete
as
begin
    set nocount on
    -- Get all FatherIDs from the Inserted and Deleted table.
    -- An ordinary Temp table is created with a clustered index to get SEEK performance later.
    -- The table might also have more than 100 rows, where table variables are not recommended.
    declare @numRowsInInsertedDeleted int
    create table #rowsInInsertedDeleted(rowId int identity(1, 1), FatherID int)
    create unique clustered index ix on #rowsInInsertedDeleted(rowId)
    insert #rowsInInsertedDeleted(FatherID)
    select  distinct f.FatherID
    from
        (
            select i.FatherID from inserted i
            union all
            select i.FatherID from deleted i
        ) f
    select @numRowsInInsertedDeleted = max(rowId) from #rowsInInsertedDeleted

    -- We have to loop each of the FatherIDs, since we might have several rows in the Inserted and Deleted tables.
    declare @rowId int = 0
    while (@rowId < @numRowsInInsertedDeleted)
    begin
        -- Get the father for the next row.
        select @rowId += 1
        declare @fatherId int
        select  @fatherId = r.FatherID
        from    #rowsInInsertedDeleted r
        where   r.rowId = @rowId
        
        -- Aggregate the mothers for this father.
        declare @motherGroup varchar(max) = ''
        select  @motherGroup += ',' + cast(c.MotherID as varchar)
        from    Child c
        where   c.FatherID = @fatherId
        group by c.MotherID 
        order by c.MotherID

        -- Update the father record.
        -- Any empty strings are handled automatically, skip the leading ','.
        update  Father
        set     MotherGroup = substring(@motherGroup, 2, 2147483647),
                MotherHash = HASHBYTES('SHA2_256', @motherGroup)
        where   FatherID = @fatherId
    end
end
go

Updating existing rows
Since you already have millions of rows, we must aggregate the mother groups for these existing rows.
If you don't have the disk space for logging the update of the whole table, maybe you should take your database out of AG and switch to Simple recovery model for this task?
In that case you should also modify the update with a WHERE clause to update only parts of the table, and run the update for each part until the whole table is updated.
Example: update Child set FatherID = FatherID where FatherID between 1 and 1000000
Note: This update statement could block access to the Child table for other users.

-- Aggregate the mother groups for the existing rows.
-- This could takes minutes to complete, depending on the number of rows.
-- NOTE: This update statement could block access to the Child table for other users.
update Child set FatherID = FatherID

That's it!
You should now be able to quickly get the mother groups on existing rows, and also after future changes in the Child table.

-- Voila - now you can get the unique mother groups any time at a fast speed.
select count(distinct MotherHash) from Father
Johnny
  • 36
  • 2
  • 1
    It is possible that the explicit `WHILE` loop could be replaced by a single query that processes all rows as a set. Usually processing row-by-row is much slower. – Vladimir Baranov Dec 05 '22 at 22:27
1

Thank you for posting such a comprehensive setup for the test data. However, I'm not running any CREATE/DROP statements against my DB so I converted those tables into table variables. Using your data, I came up with the following query. Just change the table names back to your dbo. names and you should be able to test in your environment. I basically concatenate every father/mother combo into a text string using FOR XML PATH. Then I count up all the distinct combos. If you find error in my logic, let me know. I'm just tossing this in the ring of possible solutions.

WITH distinctCombos AS (
    SELECT DISTINCT
        c.FatherID, c.MotherID
    FROM @Child as c
) , motherComboCount AS (
    SELECT
        f.FatherID
        , f.[Name]
        , STUFF((
            SELECT
                ',' + CAST(dc.MotherID as nvarchar)
            FROM distinctCombos as dc
            WHERE dc.FatherID = f.FatherID
            ORDER BY dc.MotherID ASC
            FOR XML PATH('')
        ),1,1,'') as motherList
    FROM @Father as f
)
SELECT
    COUNT(DISTINCT motherList) as UniqueMotherGroups
FROM motherComboCount as mcc

To save a bit of compute power, remove the STUFF function as it's not necessary for the comparison... it just makes the list nicer to look at if displaying... and I'm in the habit of using it.

It looks like the main differences between our methods is the use of FOR XML PATH vs STRING_AGG (I'm still on older SQL.) And I use DISTINCT twice instead of GROUP BY. If you have a larger dataset to test against, let me know how the 2 methods compare. I'm trying to think of a completely set-based method but I can't see it at the moment.

Update: Method 2. Here's an idea I had using recursive CTEs to build the distinct mother combinations. In your example data, there are only 2 mothers per father. So there would be a total of 4 set-based queries performed (first CTE, 2 queries in the recursive CTE and the final SELECT).

WITH uniqueCombo as (
    SELECT DISTINCT
        c.FatherID
        , c.MotherID
        , ROW_NUMBER() OVER(PARTITION BY c.FatherID ORDER BY c.MotherID) as row_num
    FROM @Child as c
), combos as (
    SELECT
        uc.FatherID
        , uc.MotherID
        , CAST(uc.MotherID as nvarchar(max)) as [path]
        , row_num
        , 0 as hierarchy_num
    FROM uniqueCombo as uc
    WHERE uc.row_num = 1

    UNION ALL

    SELECT
        uc.FatherID
        , uc.MotherID
        , co.[path] + ',' + CAST(uc.MotherID as nvarchar(max))
        , uc.row_num
        , co.hierarchy_num + 1 as heirarchy_num
    FROM uniqueCombo as uc
        INNER JOIN combos as co
            ON co.FatherID = uc.FatherID
            --AND co.MotherID <> uc.MotherID
            AND co.row_num + 1 = uc.row_num
), rankedCombos as (
    SELECT 
        c.[path]
        , ROW_NUMBER() OVER(PARTITION BY c.FatherID ORDER BY c.hierarchy_num DESC) as row_num
    FROM combos as c
)
SELECT COUNT(DISTINCT rc.[path]) as UniqueMotherGroups
FROM rankedCombos as rc
WHERE rc.row_num = 1

Update 2: I had another idea to use a PIVOT to transpose the records so that the FatherID would be in the left-most column with the MotherIDs as the column headers. To make that work with a dynamic list of MotherIDs, you have to use a dynamic PIVOT/dynamic SQL. (FatherID isn't really needed in the PIVOT so it's not included in the PIVOT query. I just had to describe what the goal is.) After the pivot, you can SELECT DISTINCT to get the unique mother combinations. Then the last SELECT is to get the COUNT. This one I ran in SQL Fiddle:

SQL Fiddle

MS SQL Server 2017 Schema Setup:

-- Create family tables.

CREATE TABLE dbo.Father
(
    FatherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Father
ADD CONSTRAINT PK_Father
    PRIMARY KEY CLUSTERED (FatherID);

ALTER TABLE dbo.Father SET (LOCK_ESCALATION = TABLE);

CREATE TABLE dbo.Mother
(
    MotherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Mother
ADD CONSTRAINT PK_Mother
    PRIMARY KEY CLUSTERED (MotherID);

ALTER TABLE dbo.Mother SET (LOCK_ESCALATION = TABLE);

CREATE TABLE dbo.Child
(
    ChildID INT NOT NULL
  , FatherID INT NOT NULL
  , MotherID INT NOT NULL
  , Name VARCHAR(50) NOT NULL
);

ALTER TABLE dbo.Child
ADD CONSTRAINT PK_Child
    PRIMARY KEY CLUSTERED (ChildID);

CREATE NONCLUSTERED INDEX IX_Parents ON dbo.Child (FatherID, MotherID);

ALTER TABLE dbo.Child
ADD CONSTRAINT FK_Child_Father
    FOREIGN KEY (FatherID)
    REFERENCES dbo.Father (FatherID);

ALTER TABLE dbo.Child
ADD CONSTRAINT FK_Child_Mother
    FOREIGN KEY (MotherID)
    REFERENCES dbo.Mother (MotherID);

-- Insert two children with the same parents

INSERT INTO dbo.Father
(
    FatherID
  , Name
)
VALUES
(1, 'Alex')
, (2, 'Bob')
, (3, 'Charlie')

INSERT INTO dbo.Mother
(
    MotherID
  , Name
)
VALUES
(1, 'Alice')
, (2, 'Barbara');

INSERT INTO dbo.Child
(
    ChildID
  , FatherID
  , MotherID
  , Name
)
VALUES
(1, 1, 1, 'Adam')
, (2, 1, 1, 'Billy')
, (3, 1, 2, 'Celine')
, (4, 2, 2, 'Derek')
, (5, 3, 1, 'Eric');

Query 1:

DECLARE @cols AS nvarchar(MAX)
DECLARE @query AS nvarchar(MAX)

SET @cols = STUFF((
    SELECT DISTINCT ',' + QUOTENAME(m.MotherID) 
    FROM Mother as m
    FOR XML PATH('')) 
,1,1,'')
    
SET @query = 'SELECT COUNT(mCount) as UniqueMotherGroups FROM (
    SELECT DISTINCT ' + @cols + ', 1 as mCount FROM (
        SELECT  ' + @cols + ' 
        FROM (
            SELECT
                c.FatherID
                , c.MotherID
                , 1 as mID
            FROM child as c
        ) x
        PIVOT 
        (
            MAX(mID)
            FOR MotherID in (' + @cols + ')
        ) p
    ) as m
) as mg'

--SELECT @query
Exec(@query)

Results:

| UniqueMotherGroups |
|--------------------|
|                  3 |

UPDATE 3: Here's one other idea... create a results table with a unique constraint and with IGNORE_DUP_KEY=ON. You could use this in a function or stored procedure, or, setup a trigger to put the mother combinations into a unique-combo-holding-table. With IGNORE_DUP_KEY=ON, you can insert every combo and only the unique combos will remain. Then just do a count of all the rows.

--Create a table to hold the results:
CREATE TABLE results (
  ChildID int not null
  , UniqueCombos nvarchar(50) not null
  PRIMARY KEY WITH (IGNORE_DUP_KEY = ON)
);

--Insert all combos into the results table. The unique constraint will cause only unique entries to remain.
INSERT INTO results (ChildID, UniqueCombos)
SELECT DISTINCT
  c.ChildID
  , (
    SELECT ',' + CAST(MotherID as nvarchar(500))
    FROM Child as c2
    WHERE c2.ChildID = c.ChildID
    ORDER BY c2.MotherID
    FOR XML PATH('')
  ) as mother_combos
FROM Child as c
;

--Count up all the rows in the results table. Since these are all unique combinations, it should be fast to sum.
SELECT COUNT(*)
FROM results;
Tim Jarosz
  • 1,133
  • 1
  • 8
  • 15
  • Added another Update (3)... I thought about creating a table with a column to hold unique mother combination and turn on IGNORE_DUP_KEYS. Then insert every combo no matter if it is unique or not. The Ignore dup keys option will leave only unique combinations in the results table. I'm not sure if this is any faster than the other options. But there this does have a unique advantage that you could create a trigger on the Child table so that on every insert or update, you send the mother combination into the this results table. Then you just count the rows when needed which should be fast. – Tim Jarosz Dec 01 '22 at 22:06
0

If you accept to define a maximum number of mothers per father (here 7) you may try:

select count(*) as UniqueMotherGroups from (
select distinct m1, m2, m3, m4, m5, m6, m7 from (
    select FatherID, row_number() over(partition by FatherID order by motherid) as rn, motherid
    from (
        select distinct FatherID, MotherID
        from t_Child 
    )
)
pivot (
    max(motherid) for rn in (1 as m1,2 as m2,3 as m3,4 as m4,5 as m5,6 as m6,7 as m7)
)
)
;


UNIQUEMOTHERGROUPS
------------------
                 3
p3consulting
  • 2,721
  • 2
  • 12
  • 10
0

Here is one idea. Instead of using precise STRING_AGG you can calculate a hash / checksum of the group. You don't need to know the exact composition of the group, you just need to distinguish between different groups. Calculating of the hash may be faster than concatenating strings.

SQL Server has a function CHECKSUM_AGG

You can write your own hashing function with CLR.

Sample data

CREATE TABLE #Child
(
    ChildID INT NOT NULL IDENTITY PRIMARY KEY
    ,FatherID INT NOT NULL
    ,MotherID INT NOT NULL
    ,Name VARCHAR(50) NOT NULL
);

INSERT INTO #Child
(
FatherID
,MotherID
,Name
)
VALUES
 (1, 1, 'Adam')
,(1, 1, 'Billy')
,(1, 2, 'Celine')
,(2, 2, 'Derek')
,(3, 1, 'Eric')

,(4, 1, 'A')
,(4, 1, 'B')
,(4, 2, 'C')
,(4, 2, 'D')
,(4, 2, 'E')

,(5, 2, 'F')
,(6, 2, 'G')
;

Query

WITH
distinctParentCombinations
AS
(
    SELECT
        FatherID
        ,MotherID
    FROM #Child
    GROUP BY
        FatherID
        ,MotherID
)
,motherGroups
AS
(
    SELECT
        FatherID
        ,CHECKSUM_AGG(MotherID) AS MotherGroup
    FROM distinctParentCombinations
    GROUP BY
        FatherID
)
SELECT COUNT(DISTINCT MotherGroup) AS UniqueMotherGroups
FROM motherGroups
;

Result

+--------------------+
| UniqueMotherGroups |
+--------------------+
|                  3 |
+--------------------+

You need to compare performance of all methods on your actual data.

Obviously, with CHECKSUM_AGG it is possible that some of the groups will be missed. There is a chance that two different groups will generate the same checksum.

You know better if this is acceptable.

Vladimir Baranov
  • 31,799
  • 5
  • 53
  • 90
0

General way to speed up calculations is to have some of the results already pre-calculated. In your case, for the first part you can create indexed view as follows:

CREATE OR ALTER VIEW vw_distinctParentCombinations WITH SCHEMABINDING AS
SELECT children.FatherID
         , children.MotherID
         ,COUNT_BIG(*) AS [wifes_count]
    FROM dbo.Child as children
    GROUP BY children.FatherID
           , children.MotherID

GO

CREATE UNIQUE CLUSTERED INDEX IX_vw_distinctParentCombinations ON vw_distinctParentCombinations
(
    FatherID,MotherID
);

Then in your initial query, you can avoid the first CTE:

-- CTE Gets distinct combinations of parents
WITH motherGroups (Mothers)
AS 
    (SELECT STRING_AGG(CONVERT(VARCHAR(MAX), distinctParentCombinations.MotherID), '-') WITHIN GROUP (ORDER BY distinctParentCombinations.MotherID) AS Mothers
    FROM vw_distinctParentCombinations  distinctParentCombinations WITH(NOEXPAND)
    GROUP BY distinctParentCombinations.FatherID
)

-- Remove the COUNT function to see the actual combinations
SELECT COUNT(motherGroups.Mothers) AS UniqueMotherGroups
FROM motherGroups;

This will avoid the initial read of the large table and depending the distinct combinations of the pairs (father - mother) it can reduce the view size significantly.

Unfortunately, there are a lot of limitations in order to create an indexed view, and you are not able to create such for the second CTE.

gotqn
  • 42,737
  • 46
  • 157
  • 243
0

If we change our mind and look this issue in different view, simply we can get the count of mothers with this query:

SELECT Count(distinct ConcatMothers) UniqueMothersCount from(
 SELECT FatherID,  concat(FatherID,'-',SUM(MotherID)) ConcatMothers
    FROM dbo.Child
    GROUP BY FatherID) t;

Or even you can use Dense_Rank() like this:

SELECT Max(RankMothers) UniqueMothersCount from(
 SELECT FatherID, DENSE_RANK() over (order by concat(FatherID,'-',SUM(MotherID))) RankMothers
    FROM dbo.Child
    GROUP BY FatherID) t;

For the performance it is hard to measure because dataset is small but since we have one column in the group by and the motherId is in the select maybe we can change index as below:

CREATE NONCLUSTERED INDEX IX_Parents ON dbo.Child (FatherID) Include(MotherID);

but you need to check it on your dataset.

sa-es-ir
  • 3,722
  • 2
  • 13
  • 31