cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
KevinGesquiere
Frequent Visitor

Table with measures over different periods

Is it possible to show a table with measures over different periods? It probably does, but how should I get started?

To be more precise, the data is coming from an orders table where we want an overview of the following measures.

 

                                                Last 6 months     Last 2 months      Last month

% open orders                            ....                         ....                         ....

% closed orders < 5days            ....                         ....                         ....

% closed orders 5 - 15 days       ....                         ....                         ....

% closed orders > 15days          ....                         ....                         ....

 

Thanks

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Microsoft v-jiascu-msft
Microsoft

Re: Table with measures over different periods

Hi @KevinGesquiere,

 

Please check out the demo in the attachment.

1. These conditions aren't in the source table, we can create one.

Col                                            ID

% open orders 1
% closed orders < 5days 2
% closed orders 5 - 15 days 3
% closed orders > 15days 4

2. We also need a date table.

 

Calendar = CALENDARAUTO()

3. Don't establish relationships.

4. Add calculated column to calculate days.

DaysUsed = DATEDIFF([Orderdate], [DateOrderClosed],DAY)

5. Create three measures.

Last Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

 

 

Last 6 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )
Last 2 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

Best Regards,

Dale

 

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

5 REPLIES 5
KevinGesquiere
Frequent Visitor

Table with measures over different periods

Is it possible to show a table with measures over different periods? It probably does, but how should I get started?

To be more precise, the data is coming from an orders table where we want an overview of the following measures.

 

                                                Last 6 months     Last 2 months      Last month

% open orders                            ....                         ....                         ....

% closed orders < 5days            ....                         ....                         ....

% closed orders 5 - 15 days       ....                         ....                         ....

% closed orders > 15days          ....                         ....                         ....

 

Thanks

danb Resolver I
Resolver I

Re: Table with measures over different periods

@KevinGesquiere

Can you provide a sample of your data table?

KevinGesquiere
Frequent Visitor

Re: Table with measures over different periods

@danb

It's just as an example, but here is some data (I'm not showing here all the fields from the original table). When the field DateOrderClosed is NULL then the order is still open.

 

IdOrderdateDateOrderClosed
11/05/201822/05/2018
210/05/20183/06/2018
32/06/20185/06/2018
45/06/2018NULL

 

Thanks

Highlighted
Microsoft v-jiascu-msft
Microsoft

Re: Table with measures over different periods

Hi @KevinGesquiere,

 

Please check out the demo in the attachment.

1. These conditions aren't in the source table, we can create one.

Col                                            ID

% open orders 1
% closed orders < 5days 2
% closed orders 5 - 15 days 3
% closed orders > 15days 4

2. We also need a date table.

 

Calendar = CALENDARAUTO()

3. Don't establish relationships.

4. Add calculated column to calculate days.

DaysUsed = DATEDIFF([Orderdate], [DateOrderClosed],DAY)

5. Create three measures.

Last Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

 

 

Last 6 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )
Last 2 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

Best Regards,

Dale

 

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

Microsoft v-jiascu-msft
Microsoft

Re: Table with measures over different periods

Hi @KevinGesquiere,

 

Did it work?

 

Best Regards,

Dale

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

Helpful resources

Announcements
New Ranks Launched March 24th!

New Ranks Launched March 24th!

The time has come: We are finally able to share more details on the brand-new ranks coming to the Power BI Community!

‘Better Together’ Contest Finalists Announced!

‘Better Together’ Contest Finalists Announced!

Congrats to the finalists of our ‘Better Together’-themed T-shirt design contest! Click for the top entries.

Arun 'Triple A' Event Video, Q&A, and Slides

Arun 'Triple A' Event Video, Q&A, and Slides

Missed the Arun 'Triple A' event or want to revisit it? We've got you covered! Check out the video, Q&A, and slides now.

Join THE global Microsoft Power Platform event series.

Join THE global Power Platform event series.

Attend for two days of expert-led learning and innovation on topics like AI and Analytics, powered by Dynamic Communities.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Top Solution Authors