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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
Anonymous
Not applicable

Add a period type column

Hello everyone,

 

I have created the following time table in dax and I would like to add 2 columns. The 1st one is the result of pivoting the data of 3 columns ( Month, quater and semester labels) and also add another column where I have the type of the period ( month, semester or quarter)

 

Hope this picture provides a better idea of the result i'm looking for

 

timePeriodType.PNG

 

Thank you in advance for your help,

Mariem

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Why are you using an incorrect tool for the job at hand? Would it not be 10000000000 times easier to do all of this in Power Query? Most of this is just a mouse click away... What's more, you'll find read-made M code on the net that builds all of this and even more for you. Please do use the right tool for the job.

 

On top of that, a proper date table contains all years with all their days, without any gaps and miscontinuations. It seems you're not following this Best Practice.

View solution in original post

v-yiruan-msft
Community Support
Community Support

Hi @Anonymous ,

You can update the formula of your calculated table as below:

Date =
VAR _cal =
    CALENDAR (
        MIN ( 'FactAssignmentByDay'[TIMEBYDAY_DT] ),
        MAX ( 'FactAssignmentByDay'[TIMEBYDAY_DT] )
    )
VAR _temptab =
    ADDCOLUMNS (
        _cal,
        "Year"YEAR ( [Date] ),
        "Month num"MONTH ( [Date] ),
        "Month"FORMAT ( [Date], "MMM" ),
        "Month LB"CONCATENATE ( FORMAT ( [Date], "YYYY" )CONCATENATE ( "M"MONTH ( [Date] ) ) ),
        "Quarter"CONCATENATE ( "Q"QUARTER ( [Date] ) ),
        "Quarter LB",
            CONCATENATE (
                FORMAT ( [Date], "YYYY" ),
                CONCATENATE ( "Q"QUARTER ( [Date] ) )
            ),
        "Semester"IF ( MONTH ( [Date] ) <= 6"S1""S2" ),
        "Semester LB",
            IF (
                MONTH ( [Date] ) <= 6,
                CONCATENATE ( FORMAT ( [Date], "YYYY" )" S1" ),
                CONCATENATE ( FORMAT ( [Date], "YYYY" )" S2" )
            )
    )
RETURN
    UNION (
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Quarter LB],
            "TimePeriod""Quarter"
        ),
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Month LB],
            "TimePeriod""Month"
        ),
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Semester LB],
            "TimePeriod""Semester"
        )
    )

yingyinr_0-1626746870755.png

Best Regards

Community Support Team _ Rena
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

2 REPLIES 2
v-yiruan-msft
Community Support
Community Support

Hi @Anonymous ,

You can update the formula of your calculated table as below:

Date =
VAR _cal =
    CALENDAR (
        MIN ( 'FactAssignmentByDay'[TIMEBYDAY_DT] ),
        MAX ( 'FactAssignmentByDay'[TIMEBYDAY_DT] )
    )
VAR _temptab =
    ADDCOLUMNS (
        _cal,
        "Year"YEAR ( [Date] ),
        "Month num"MONTH ( [Date] ),
        "Month"FORMAT ( [Date], "MMM" ),
        "Month LB"CONCATENATE ( FORMAT ( [Date], "YYYY" )CONCATENATE ( "M"MONTH ( [Date] ) ) ),
        "Quarter"CONCATENATE ( "Q"QUARTER ( [Date] ) ),
        "Quarter LB",
            CONCATENATE (
                FORMAT ( [Date], "YYYY" ),
                CONCATENATE ( "Q"QUARTER ( [Date] ) )
            ),
        "Semester"IF ( MONTH ( [Date] ) <= 6"S1""S2" ),
        "Semester LB",
            IF (
                MONTH ( [Date] ) <= 6,
                CONCATENATE ( FORMAT ( [Date], "YYYY" )" S1" ),
                CONCATENATE ( FORMAT ( [Date], "YYYY" )" S2" )
            )
    )
RETURN
    UNION (
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Quarter LB],
            "TimePeriod""Quarter"
        ),
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Month LB],
            "TimePeriod""Month"
        ),
        SELECTCOLUMNS (
            _temptab,
            "Year", [Year],
            "Month num", [Month num],
            "Month", [Month],
            "Quarter", [Quarter],
            "Semester", [Semester],
            "Label", [Semester LB],
            "TimePeriod""Semester"
        )
    )

yingyinr_0-1626746870755.png

Best Regards

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

Why are you using an incorrect tool for the job at hand? Would it not be 10000000000 times easier to do all of this in Power Query? Most of this is just a mouse click away... What's more, you'll find read-made M code on the net that builds all of this and even more for you. Please do use the right tool for the job.

 

On top of that, a proper date table contains all years with all their days, without any gaps and miscontinuations. It seems you're not following this Best Practice.

Helpful resources

Announcements
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!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

Feb2025 NL Carousel

Fabric Community Update - February 2025

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

Top Kudoed Authors