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

Calculate sum of the difference between 2 columns from different table

EDIT:
Thank you all for the help, but I just found a solution for my problem

_________________________________________________________________________________________
Hi.
I have 2 tables:

Table Team: that has 3 columns: the names of the employees, their date of admission and, if applied, the date when they left the company

Table BSC: that has 2 columns: years and months, since 2020

I want to know how long my employees stayed in my company at the different dates on the BSC table. To simplify, for now, I am not considering the date they left the company. I created a representation on excel to make it simpler to understand. 

alexandra__1-1652892205349.png

Basically for each combination of year/month in my BSC table, I create a new column in the BSC table with sum of the difference between the last day of that month and the date of admission for all my employees.
My DAX code would look like this:
Column = CALCULATE( SUMX (Team, Team[dateofadmission] - DATE( BSC[year], BSC[month], DAY(EOMONTH(DATE(BSC[year], BSC[month],1),0)) , FILTER (...) )
The problem with this formula is that I can't retrieve the columns from both of my tables. Do you have any idea of how I can calculate this?
Thank you

1 ACCEPTED SOLUTION

Hi @Anonymous 

something like this

NewMeasure =
VAR CurrentMonth =
    SELECTEDVALUE ( BSC[month] )
VAR CurrentYear =
    SELECTEDVALUE ( BSC[year] )
VAR CurrentDate =
    DATE ( CurrentYear, CurrentMonth, DAY ( EOMONTH ( DATE ( CurrentYear, CurrentMonth, 1 ), 0 ) ) )
RETURN
    SUMX (
        Team,
        VAR StartDate = Team[dateofadmission]
        VAR EndDate =
            IF (
                ISBLANK ( Team[dateoftermination] ),
                CurrentDate,
                MAX ( CurrentDate, Team[dateoftermination] )
            )
        RETURN
            EndDate - StartDate
    )

View solution in original post

5 REPLIES 5
tamerj1
Super User
Super User

Hi @Anonymous 

why don't you just creat a table visual as a measure?

Anonymous
Not applicable

I'm sorry, but can you explain better how to do that?

Hi @Anonymous 

something like this

NewMeasure =
VAR CurrentMonth =
    SELECTEDVALUE ( BSC[month] )
VAR CurrentYear =
    SELECTEDVALUE ( BSC[year] )
VAR CurrentDate =
    DATE ( CurrentYear, CurrentMonth, DAY ( EOMONTH ( DATE ( CurrentYear, CurrentMonth, 1 ), 0 ) ) )
RETURN
    SUMX (
        Team,
        VAR StartDate = Team[dateofadmission]
        VAR EndDate =
            IF (
                ISBLANK ( Team[dateoftermination] ),
                CurrentDate,
                MAX ( CurrentDate, Team[dateoftermination] )
            )
        RETURN
            EndDate - StartDate
    )
Anonymous
Not applicable

llo

 

Try this

Employee calc is my name table

JamesFr06_0-1652894470628.png

 

Anonymous
Not applicable

The problem is that, in reality, that information is on 2 separate tables
I just put it like that in the excel to explain what I wanted to do

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.