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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
matherhorn64
Frequent Visitor

Weeks after the beginning of month

Hi guys,

 

I would like to compare quality of customers by month. On Y-axis should be values, on X-axis - days (weeks) after the beginning of a month (from 1 up till 365 or from 1 up till 52), in legend - months. The idea is simply to look at the quality of customers in the beginning of each month and then moving forward. I'm really struggling to figure our how to make this "days/weeks after beginning of a month" thing happen and looking forward for your help.

 

Attaching a graph screenshot made in excel for your better understanding what i'm trying to do 

 

Снимок.PNG

1 ACCEPTED SOLUTION
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @matherhorn64,

 

Actually, your requirement cannot be achieved in a line chart. Because you were attempting to display some data that is not existing in a month. For example, for February it will show up to 48 days starting from 0, while in February there are only 28 data rows, the data from day 29 to day 48 comes from March, however, in a chart, under each group instance (Month), it can not show the non-existing data values.

 

If you indeed want that output, you can try below workaround. It would be complex if there are many data records in table view. 

 

The sample table used in my test contains two columns, [Date] and [Amount]. 

 

I added some calculated columns as below:

Day for Jan =
DATEDIFF ( MIN ( 'STARTOFMONTH'[Date] ), MAX ( 'STARTOFMONTH'[Date] ), DAY )
    - DATEDIFF ( 'STARTOFMONTH'[Date], MAX ( 'STARTOFMONTH'[Date] ), DAY )

Jan = "Jan"

Day for Feb =
IF (
    'STARTOFMONTH'[Date].[MonthNo] >= 2,
    DATEDIFF (
        MINX (
            FILTER ( 'STARTOFMONTH', 'STARTOFMONTH'[Date].[MonthNo] = 2 ),
            'STARTOFMONTH'[Date]
        ),
        MAX ( 'STARTOFMONTH'[Date] ),
        DAY
    )
        - DATEDIFF ( 'STARTOFMONTH'[Date], MAX ( 'STARTOFMONTH'[Date] ), DAY ),
    BLANK ()
)

Feb = "Feb"

2.PNG

 

Then, create a calculated table.

Table =
UNION (
    SELECTCOLUMNS (
        'STARTOFMONTH',
        "Amount", 'STARTOFMONTH'[Amount],
        "Day", 'STARTOFMONTH'[Day for Jan],
        "Month", 'STARTOFMONTH'[Jan]
    ),
    SELECTCOLUMNS (
        'STARTOFMONTH',
        "Amount", 'STARTOFMONTH'[Amount],
        "Day", 'STARTOFMONTH'[Day for Feb],
        "Month", 'STARTOFMONTH'[Feb]
    )
)

3.PNG

 

In a line chart visual, add Table[Amount] as Values, add Table[Day] as Axis, add Table[Month] as Legend.

4.PNG

 

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @matherhorn64,

 

Actually, your requirement cannot be achieved in a line chart. Because you were attempting to display some data that is not existing in a month. For example, for February it will show up to 48 days starting from 0, while in February there are only 28 data rows, the data from day 29 to day 48 comes from March, however, in a chart, under each group instance (Month), it can not show the non-existing data values.

 

If you indeed want that output, you can try below workaround. It would be complex if there are many data records in table view. 

 

The sample table used in my test contains two columns, [Date] and [Amount]. 

 

I added some calculated columns as below:

Day for Jan =
DATEDIFF ( MIN ( 'STARTOFMONTH'[Date] ), MAX ( 'STARTOFMONTH'[Date] ), DAY )
    - DATEDIFF ( 'STARTOFMONTH'[Date], MAX ( 'STARTOFMONTH'[Date] ), DAY )

Jan = "Jan"

Day for Feb =
IF (
    'STARTOFMONTH'[Date].[MonthNo] >= 2,
    DATEDIFF (
        MINX (
            FILTER ( 'STARTOFMONTH', 'STARTOFMONTH'[Date].[MonthNo] = 2 ),
            'STARTOFMONTH'[Date]
        ),
        MAX ( 'STARTOFMONTH'[Date] ),
        DAY
    )
        - DATEDIFF ( 'STARTOFMONTH'[Date], MAX ( 'STARTOFMONTH'[Date] ), DAY ),
    BLANK ()
)

Feb = "Feb"

2.PNG

 

Then, create a calculated table.

Table =
UNION (
    SELECTCOLUMNS (
        'STARTOFMONTH',
        "Amount", 'STARTOFMONTH'[Amount],
        "Day", 'STARTOFMONTH'[Day for Jan],
        "Month", 'STARTOFMONTH'[Jan]
    ),
    SELECTCOLUMNS (
        'STARTOFMONTH',
        "Amount", 'STARTOFMONTH'[Amount],
        "Day", 'STARTOFMONTH'[Day for Feb],
        "Month", 'STARTOFMONTH'[Feb]
    )
)

3.PNG

 

In a line chart visual, add Table[Amount] as Values, add Table[Day] as Axis, add Table[Month] as Legend.

4.PNG

 

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Brilliant, thanks!

chbraun
Helper I
Helper I

DAX to the rescue! 🙂 Just create a calculated column in your date table like this:

 

days after start of month = DATEDIFF(STARTOFMONTH(Dates[Date]), Dates[Date], DAY)

 

That should do the trick.

Hi chbraun, thanks a lot for your response!

 

Your solution works for comparison, but it will show only the days from 1 to 30 for each month.

 

Is there any way to present graphically the information with ALL the days after the beginning of each month? For instance, now is 20.03.2017 so for March the line graph will show the trend for 20 days starting from 0, for February it will show up to 48 days starting from 0, etc. Attaching the screenshot of what I have in mind:)
Снимок.PNG

 

 

 

 

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.