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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
AngelaB
Helper I
Helper I

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

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

View solution in original post

2 REPLIES 2
AngelaB
Helper I
Helper I

Hello @Anonymous - 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.

Anonymous
Not applicable

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

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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