Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
StephenK
Resolver I
Resolver I

Matrix Visual Display Top Domain by Count

Hey all,

 

I need help displaying something correctly in my matrix visual. I have two tables--

1) Users Tbl

2) Domains Tbl

 

I need to display a matrix visual like the following:

UserDomain CountTop Domain
some user25google.com
another user15yahoo.com
TOTAL40google.com

 

By default, the matrix visual displays the first or last domain. Can anyone help me create a measure that will output the Domain  based on the Domain Count? The total should reflect the entire dataset irrespective of user, but by row it should show the top domain by user. Hope that makes sense!

 

Any help is appreciated.

1 ACCEPTED SOLUTION

@StephenK,

 

Your measure is missing a CALCULATE for the COUNT expression in the variables vUserDomain and vAllDomain. Alternatively, you can use a measure, resulting in an implicit CALCULATE. The correct measures are below:

 

Domain Count = COUNT ( Domains[Domain] )

Top Domain = 
VAR vUser =
    MAX ( Users[UserId] )
VAR vUserDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[UserId], Domains[Domain] ),
        "DomainCount", [Domain Count]
    )
VAR vUserDomainRank =
    ADDCOLUMNS (
        vUserDomain,
        "DomainRank", RANKX ( vUserDomain, [DomainCount],, DESC, DENSE )
    )
VAR vUserTopDomainRow =
    FILTER ( vUserDomainRank, [DomainRank] = 1 )
VAR vUserTopDomain =
    MAXX ( vUserTopDomainRow, Domains[Domain] )
VAR vAllDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[Domain] ),
        "DomainCount", [Domain Count]
    )
VAR vAllDomainRank =
    ADDCOLUMNS (
        vAllDomain,
        "DomainRank", RANKX ( vAllDomain, [DomainCount],, DESC, DENSE )
    )
VAR vAllTopDomainRow =
    FILTER ( vAllDomainRank, [DomainRank] = 1 )
VAR vAllTopDomain =
    MAXX ( vAllTopDomainRow, Domains[Domain] )
RETURN
    IF ( HASONEVALUE ( Users[UserName] ), vUserTopDomain, vAllTopDomain )

 

DataInsights_0-1604098097031.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

11 REPLIES 11
v-yiruan-msft
Community Support
Community Support

Hi @StephenK ,

Could you please provide some sample data of table Users and Domains and your desired result with examples? Whether exist any relationship between these two tables? If yes, could you please also provide the relationship field? By the way, Domain Count is the number of users grouped by domain? User field display the specific user name?

Best Regards
Rena
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@DataInsights @v-yiruan-msft Here is the sample data.. there is a 1 to many relationship on the UserId column. Domain count should be the count of VisitId by domain.

 

UserId  UserName

1John Smith
2Jane Doe
3Sally May
4Roy Rogers
5Sam Brown

 

VisitId  UserId     Domain

11google.com
21facebook.com
31google.com
41google.com
52twitter.com
62twitter.com
72facebook.com
83adp.com
93yahoo.com
104google.com
114google.com
125facebook.com
135facebook.com

@StephenK,

 

Here's the result I get. The second visual shows that google.com has the most visits, which is what displays on the total row of the first visual. Is this the correct result?

 

DataInsights_0-1603897783405.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




@DataInsights that is the correct result in your screenshots, but for some reason it's not what i'm getting when I implement the formula in my project file. The totals row is showing the domain with the least number of visits. I've tried tweaking the formula in different ways just to see how the output changes. Changing the sort order of RANKX does nothing. Changing MAXX to MINX indicates something interesting.

 

MAXX is currently pulling the very last domain in the table with 1 visit. Changing to MINX pulls the first domain in the table with 1 visit. I can't figure out why the formula keeps pulling domains with the lowest visit counts.

@StephenK,

 

Would you be able to provide a sanitized version of your pbix? You can remove everything unrelated. If not, would you post your measure?





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




@DataInsights  Here you go: TopDomains.pbix (OneDrive) 

I've included a screen shot as well which shows the problem. Blue = correct value. Red = Incorrect. The visuals on the right are a reference on what the correct output should be. Thanks for your help!

screenshot.PNG

@StephenK,

 

Your measure is missing a CALCULATE for the COUNT expression in the variables vUserDomain and vAllDomain. Alternatively, you can use a measure, resulting in an implicit CALCULATE. The correct measures are below:

 

Domain Count = COUNT ( Domains[Domain] )

Top Domain = 
VAR vUser =
    MAX ( Users[UserId] )
VAR vUserDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[UserId], Domains[Domain] ),
        "DomainCount", [Domain Count]
    )
VAR vUserDomainRank =
    ADDCOLUMNS (
        vUserDomain,
        "DomainRank", RANKX ( vUserDomain, [DomainCount],, DESC, DENSE )
    )
VAR vUserTopDomainRow =
    FILTER ( vUserDomainRank, [DomainRank] = 1 )
VAR vUserTopDomain =
    MAXX ( vUserTopDomainRow, Domains[Domain] )
VAR vAllDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[Domain] ),
        "DomainCount", [Domain Count]
    )
VAR vAllDomainRank =
    ADDCOLUMNS (
        vAllDomain,
        "DomainRank", RANKX ( vAllDomain, [DomainCount],, DESC, DENSE )
    )
VAR vAllTopDomainRow =
    FILTER ( vAllDomainRank, [DomainRank] = 1 )
VAR vAllTopDomain =
    MAXX ( vAllTopDomainRow, Domains[Domain] )
RETURN
    IF ( HASONEVALUE ( Users[UserName] ), vUserTopDomain, vAllTopDomain )

 

DataInsights_0-1604098097031.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




@DataInsights that did it! Thanks so much for your help! Greatly appreciated.

DataInsights
Super User
Super User

@StephenK,

 

Try this measure:

 

Top Domain =
VAR vUser =
    MAX ( Users[User ID] )
VAR vUserDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[User ID], Domains[Domain] ),
        "DomainCount", Domains[Domain Count]
    )
VAR vUserDomainRank =
    ADDCOLUMNS (
        vUserDomain,
        "DomainRank", RANKX ( vUserDomain, [DomainCount],, DESC, DENSE )
    )
VAR vUserTopDomainRow =
    FILTER ( vUserDomainRank, [DomainRank] = 1 )
VAR vUserTopDomain =
    MAXX ( vUserTopDomainRow, Domains[Domain] )
VAR vAllDomain =
    ADDCOLUMNS (
        SUMMARIZE ( Domains, Domains[Domain] ),
        "DomainCount", Domains[Domain Count]
    )
VAR vAllDomainRank =
    ADDCOLUMNS (
        vAllDomain,
        "DomainRank", RANKX ( vAllDomain, [DomainCount],, DESC, DENSE )
    )
VAR vAllTopDomainRow =
    FILTER ( vAllDomainRank, [DomainRank] = 1 )
VAR vAllTopDomain =
    MAXX ( vAllTopDomainRow, Domains[Domain] )
RETURN
    IF ( HASONEVALUE ( Users[User Name] ), vUserTopDomain, vAllTopDomain )




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Thanks for this @DataInsights! It seems to be working at the row level, but the domain displayed on the total line is incorrect. It appears to be showing the domain with the lowest domain count. I tried changing the sort on the RANKX functions to ASC just to see if that fixed it, but it did not

@StephenK,

 

Would you be able to provide some sample data (that I can copy/paste) that illustrates the issue? It's working correctly for the sample data I created.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.