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
Anonymous
Not applicable

Measure or column? How to sum data from two unrelated tables

Hi!

 

I’m working with two large datasets that aren’t related. Neither table has a column of unique values.

 

I need to create charts that show the stock level from each store in both datasets by item name, region name, and store name.

 

I’ve tried to make a clustered column chart with a measure but I end up with stuff on the chart that Power BI calls (Blank). Looking closely at the (Blank) stuff shows that Power BI is calling items in one of the tables (Blank) rather than the actual item name.

 

Then I tried to make a new column in a table that just had a list of all the different stock items but then the clustered column charts shows that all stores have the same stock levels.

 

How can I sum the stock levels from the two datasets and display them on a chart?

 

Thanks in advance!

 

Here are examples of what my datasets are like:

National DataNational DataLocal InfoLocal InfoThis is what I want to get displayed.This is what I want to get displayed.

1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

Hi @Anonymous,

 

You can create two tables to store merged 'shop' records and 'product' records, then use shop table as axis, product as legend to create a clustered column chart.


After these, write a measure to summary records from two tables and use it in value field.

 

Calculate tables:

 

DimShop=
DISTINCT(UNION(VALUES(TABLE1[Shop]),VALUES(TABLE2[Store])))

DimProduct=
DISTINCT(UNION(VALUES(TABLE1[Product]),VALUES(TABLE2[Item])))

 

 

Measure formula:

 

Measure =
VAR summary =
    UNION (
        SELECTCOLUMNS ( TABLE1, "Shop", [Shop], "Product", [Product], "Stock", [Stock] ),
        SELECTCOLUMNS ( TABLE2, "Shop", [Store], "Product", [Item], "Stock", [Quanity] )
    )
RETURN
    SUMX (
        FILTER (
            summary,
            [Shop] IN VALUES ( DimShop[Shop] )
                && [Product] IN VALUES ( DimProduct[Product] )
        ),
        [Stock]
    )

 

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

4 REPLIES 4
v-shex-msft
Community Support
Community Support

Hi @Anonymous,

 

You can create two tables to store merged 'shop' records and 'product' records, then use shop table as axis, product as legend to create a clustered column chart.


After these, write a measure to summary records from two tables and use it in value field.

 

Calculate tables:

 

DimShop=
DISTINCT(UNION(VALUES(TABLE1[Shop]),VALUES(TABLE2[Store])))

DimProduct=
DISTINCT(UNION(VALUES(TABLE1[Product]),VALUES(TABLE2[Item])))

 

 

Measure formula:

 

Measure =
VAR summary =
    UNION (
        SELECTCOLUMNS ( TABLE1, "Shop", [Shop], "Product", [Product], "Stock", [Stock] ),
        SELECTCOLUMNS ( TABLE2, "Shop", [Store], "Product", [Item], "Stock", [Quanity] )
    )
RETURN
    SUMX (
        FILTER (
            summary,
            [Shop] IN VALUES ( DimShop[Shop] )
                && [Product] IN VALUES ( DimProduct[Product] )
        ),
        [Stock]
    )

 

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
Anonymous
Not applicable

Hi Xiaoxin Sheng,

 

Thanks for this solution. It worked!

 

Sorry for the large time lag between your response and my reply. It took me a bit to try to understand the solution and work with it.

 

Thanks so much!

Greg_Deckler
Super User
Super User

Power BI does support many-to-many now and you could create a bridge table. Also, perhaps you could create a concatenated column that uniquely identifies each shop (shop & region). Generally you get blanks in Power BI when things don't quite match up.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

Hi Greg,

 

I can't find a many-to-many option in the Edit Relationships window and Power BI gives me an error when I try to relate the Item and Product columns saying that one column must have unique values.

 

Is my version of Power BI recent enough to have the many-to-many relationship? Where would it be located?

 

Thanks so much for your help!!

 

Power BI program info.PNG

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.

Top Solution Authors