cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
KevinGesquiere Frequent Visitor
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
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
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 Member
Member

Re: Table with measures over different periods

@KevinGesquiere

Can you provide a sample of your data table?

KevinGesquiere Frequent Visitor
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

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
Exclusive LIVE Community Event #3 – Ask Arun Anything

Exclusive LIVE Community Event #3 – Ask Arun Anything

Join us in the third Triple A event!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

January 2020 Community Highlights

January 2020 Community Highlights

Make sure you didn't miss any of the things that happened in the community in January!

Difinity Conference

Difinity Conference

The largest Power BI, Power Platform, and Data conference in New Zealand

Top Solution Authors
Top Kudoed Authors