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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
AngelaB
Frequent Visitor

Combining data from two tables when data is in different format

Hello fabulous Fabric community. I will do my best to describe my problem to see if what I'm trying to do is even possible. I have also included some sample data below to show what I mean.

 

I have two data sources that I'm trying to combine to be able to use them as a single field in reports. The two sources have come about because we changed how this data was being collected about 12 months ago (but can still be combined so don't worry about that). This means I've ended up with the data sitting across two tables -

- Table 1: the value is a summarised value (%) by ward (historical data prior to 2022)

- Table 2: the value is 'raw' or unsummarised data by response by ward. I then have a calculated measure where I summarise this as a percentage by facility (current data from 2022 onwards)

 

I would like to combine the two to allow me to display the summarised value across time in visualisations.

 

I suspect this will need a multi-step transformation but can't work it out.

 

Here is some sample data to illustrate what I mean:

Table 1. Historical summarised data

WardTimepoint%MOB%NUTR%COG
Ward1120%50%10%
Ward1220%0%0%
Ward2150%30%10%
Ward2260%20%0%
Ward2360%20%0%

 

Table 2. Current unsummarised data

WardTimepointMOBNUTRCOG
Ward13YesNoNo
Ward13NoNoYes
Ward13NoNoNo
Ward13YesYesNo
Ward13YesYesNo
Ward13YesNoNo
Ward13YesNoNo
Ward13NoYesNo
Ward13YesYesYes
Ward24YesNoNo
Ward24NoNoYes
Ward24NoNoNo
Ward24YesYesNo
Ward24YesYesNo
Ward24YesNoNo
Ward24YesNoNo
Ward24NoYesNo
Ward24YesYesYes

 

I would like to be able to show data for Ward 1 across timepoints 1-3 in the same visualisation so need to get these combined somehow.

 

Thanks 🙂

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

HI @AngelaB,

Here is the calculated table formula to union two table and convert their records to same format, you can try to use it if suitable for your requirement.

 

Merged =
UNION (
    SELECTCOLUMNS (
        'Table1',
        'Table1'[Ward],
        'Table1'[Timepoint],
        "COG", 'Table1'[%COG],
        "MOB", 'Table1'[%MOB],
        "NUTR", 'Table1'[%NUTR]
    ),
    SUMMARIZE (
        'Table2',
        'Table2'[Ward],
        'Table2'[Timepoint],
        "COG",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[COG] = "Yes" ),
                COUNTROWS ( 'Table2' )
            ),
        "MOB",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[MOB] = "Yes" ),
                COUNTROWS ( 'Table2' )
            ),
        "NUTR",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[COG] = "Yes" ),
                COUNTROWS ( 'Table2' )
            )
    )
)

 

1.png

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

2 REPLIES 2
AngelaB
Frequent Visitor

Hello @v-shex-msft - thank you so much for this solution (and sorry for the delayed response, leave over the Festive period and all that).

 

I have implemented this using a new calculated table and it appears to have worked (no DAX errors etc), however the resultant merged table is patchy... some of the pre-2022 data has come through and some of the post-2022 data has come through, but there are gaps for both which is really odd. Any thoughts on what would cause a glitch like that?

 

Thanks again, Angela.

v-shex-msft
Community Support
Community Support

HI @AngelaB,

Here is the calculated table formula to union two table and convert their records to same format, you can try to use it if suitable for your requirement.

 

Merged =
UNION (
    SELECTCOLUMNS (
        'Table1',
        'Table1'[Ward],
        'Table1'[Timepoint],
        "COG", 'Table1'[%COG],
        "MOB", 'Table1'[%MOB],
        "NUTR", 'Table1'[%NUTR]
    ),
    SUMMARIZE (
        'Table2',
        'Table2'[Ward],
        'Table2'[Timepoint],
        "COG",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[COG] = "Yes" ),
                COUNTROWS ( 'Table2' )
            ),
        "MOB",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[MOB] = "Yes" ),
                COUNTROWS ( 'Table2' )
            ),
        "NUTR",
            DIVIDE (
                CALCULATE ( COUNTROWS ( 'Table2' ), 'Table2'[COG] = "Yes" ),
                COUNTROWS ( 'Table2' )
            )
    )
)

 

1.png

Regards,

Xiaoxin Sheng

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

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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