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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
sbuster
Helper I
Helper I

Query optimization assistance

Hello,
I am trying to see if there is a way to optimize the measure in the sample attachment.  The model details an asset (automobile) with events (EventFacts) on a given date.  Each automobile may or may not be associated with a configuration (AssetEventMapping). 

What I would like is a distinct count of assets by day (see DateTable) only if the asset has a configuration associate in the AssetEventMapping table.

 

The model details below show example tables & records with the desired result.  As can be seen, assets 6 and 7 do not show up in daily count because they do not contain a record in the mapping table (filtered out via the "in distinct" portion of hte measure).

 

This measure works fine with small dataset, but my real dataset contains millions of records and this query is taking ~5 seconds.

 

Thanks

 

Tables:

sbuster_0-1681833017769.png

 

Measure:

Count of Assets Reporting =
    calculate(
        DISTINCTCOUNT(EventFacts[AssetId]),
        FILTER(
            EventFacts,
            EventFacts[AssetID] in (distinct(AssetEventMapping[AssetID]))
        )
    )
1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @sbuster 

Please try

Count of Assets Reporting =
COUNTROWS (
DISTINCT (
SELECTCOLUMNS (
FILTER (
EventFacts,
EventFacts[AssetID] IN ( DISTINCT ( AssetEventMapping[AssetID] ) )
),
"@AssetID", EventFacts[AssetId]
)
)
)

View solution in original post

2 REPLIES 2
tamerj1
Super User
Super User

Hi @sbuster 

Please try

Count of Assets Reporting =
COUNTROWS (
DISTINCT (
SELECTCOLUMNS (
FILTER (
EventFacts,
EventFacts[AssetID] IN ( DISTINCT ( AssetEventMapping[AssetID] ) )
),
"@AssetID", EventFacts[AssetId]
)
)
)

Thanks for you response, that improved performance significantly!


Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.