cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Pbiuserr
Post Prodigy
Post Prodigy

How to achieve such table

Hello

I have table with project hours and table with hours outside the project. I'd like to produce a final table like in the capture. I've put only columns mandatory for that, there are plenty in both (not equal amount, but I am interested mainly in those for that visual). Is it something I can achieve via DAX/PQ?

 

Pbiuserr_0-1670498718384.png

 

Thank you in advance for your help

1 ACCEPTED SOLUTION
PaulDBrown
Super User
Super User

Here is one way.

First add a new column to each table to establish the "Type":

Type col.jpg

Add a new column to the outside hours table for "project":

outside project.jpgCreate dimension tables for both employee and type following this pattern:

 

Employee table = 
DISTINCT(
    UNION(
    VALUES('On Project Table'[Emp ID]), VALUES('On Project Table'[Emp ID])))

 

employee table.jpg

Create a dimension table for project using:

 

Project Table = 
ADDCOLUMNS(
    DISTINCT(
        UNION(
            VALUES('On Project Table'[ProjectDsc]), VALUES('Out of hours Table'[Project]))),
            "Project", IF([ProjectDsc] = "No Project", BLANK(), [ProjectDsc]))
           

 

project table.jpg

Set up the model as follows

model.jpg

Create a measure for the hours:

 

Sum Hours = 
SUM('On Project Table'[Hours on Project]) + SUM('Out of hours Table'[Hours outside project])

 

Set up a table visual using the fields from the dimension tables and the measure to get:

result.jpg

 

Sample PBIX file attached 

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

3 REPLIES 3
PaulDBrown
Super User
Super User

Here is one way.

First add a new column to each table to establish the "Type":

Type col.jpg

Add a new column to the outside hours table for "project":

outside project.jpgCreate dimension tables for both employee and type following this pattern:

 

Employee table = 
DISTINCT(
    UNION(
    VALUES('On Project Table'[Emp ID]), VALUES('On Project Table'[Emp ID])))

 

employee table.jpg

Create a dimension table for project using:

 

Project Table = 
ADDCOLUMNS(
    DISTINCT(
        UNION(
            VALUES('On Project Table'[ProjectDsc]), VALUES('Out of hours Table'[Project]))),
            "Project", IF([ProjectDsc] = "No Project", BLANK(), [ProjectDsc]))
           

 

project table.jpg

Set up the model as follows

model.jpg

Create a measure for the hours:

 

Sum Hours = 
SUM('On Project Table'[Hours on Project]) + SUM('Out of hours Table'[Hours outside project])

 

Set up a table visual using the fields from the dimension tables and the measure to get:

result.jpg

 

Sample PBIX file attached 

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Thanks
Can i make a matrix out of it, to look like that

rows: 

first layer be manager (assume its field in first table)
on project / outside

employee (assume its field in first table)
hours 

?

Sure! To cater for the added field for manager, change the Employe table to the following:

Employee table = 
   SUMMARIZE('On Project Table', 'On Project Table'[Emp ID], 'On Project Table'[Manager])

employee table.jpgmatrix.jpg

Sample PBIX file attached





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

BizApps LATAM 2023

Business Application LATAM Summit 2023

Join the biggest FREE Business Applications Event in LATAM this February.

Power Platform Bootcamp

Global Power Platform Bootcamp

In this bootcamp we will deep-dive into Microsoft’s Power Platform stack with hands-on sessions and labs, delivered to you by experts and community leaders.