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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
fleming507
Frequent Visitor

Number of Days Value to Rows

 I have a dataset that I need to maniuplate for year end reporting, but the data from source is not entirely suitable. For each service there is a Scheduled Start Date and Numbder of days scheduled. What I'm trying to do is join it on to a calendar table (or something else) so that I have a row for each day scheduled (excluding weekends)

 

eg,

 

ServiceName    ScheduledStartDate   NumberOfDays

InstallApp         19/07/2018                5.0

 

to become...

 

ServiceName   ScheduledDate

InstallApp        19/07/18

InstallApp        20/07/18

InstallApp        23/07/18

InstallApp        24/07/18

InstallApp        25/07/18

 

I have a good idea how I would do this in SQL, but im trying to avoid using a database layer in between

 

Thanks

1 ACCEPTED SOLUTION
Zubair_Muhammad
Community Champion
Community Champion

Hi @fleming507

 

Try this calculated table. Assuming your table name is Table1

 

Table =
VAR Temp1 =
    GENERATE (
        Table1,
        VAR mydays =
            CALCULATE (
                VALUES ( Table1[ NumberOfDays] ),
                Table1[ServiceName] = EARLIER ( Table1[ServiceName] )
            )
        VAR adddays =
            (
                INT ( mydays / 7 )
                    + 1
            )
                * 2
        RETURN
            GENERATESERIES ( 1, mydays + adddays )
    )
VAR temp2 =
    ADDCOLUMNS (
        ADDCOLUMNS ( Temp1, "Scheduled Dates", [ScheduledStartDate ] + [Value] - 1 ),
        "WeekDay", WEEKDAY ( [Scheduled Dates], 2 )
    )
VAR temp3 =
    FILTER ( temp2, [WeekDay] < 6 )
VAR temp4 =
    ADDCOLUMNS (
        temp3,
        "RANK", RANKX (
            FILTER ( temp3, [ServiceName] = EARLIER ( [ServiceName] ) ),
            [Scheduled Dates],
            ,
            ASC,
            DENSE
        )
    )
VAR temp5 =
    FILTER ( temp4, [RANK] <= [ NumberOfDays] )
RETURN
    SUMMARIZE ( temp5, [ServiceName], [Scheduled Dates] )

Regards
Zubair

Please try my custom visuals

View solution in original post

7 REPLIES 7
parry2k
Super User
Super User

You can also achieve this by power query, here is link to a post which describe how this can be done?

 

https://community.powerbi.com/t5/Desktop/Convert-date-ranges-into-list-of-dates/td-p/129418

 

https://community.powerbi.com/t5/Desktop/Get-a-list-of-dates-from-range-and-schedule/td-p/174811

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

fleming507
Frequent Visitor

I thought I replied to this, seems to have disappeared.

 

This solution works in most cases but where service may be 0.5 or 1 even 2 days it seems to add an extra day on the end.

@fleming507

 

Hi,

 

Could you give me an example of a service and date where itis not working

 

I tried with 1 and 2 days (file attached as well). It seems to be working. .....But may be I am missing something

 

no.png


Regards
Zubair

Please try my custom visuals

Thanks zubair, on further review my data was erronous. once corrected I achieved the desired reults with the original solution.

v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @fleming507,

 

The answer of @Zubair_Muhammad should solve your problem.

 

If you have solved your problem, please accept the replies making sense as solution to your question so that people who may have the same question can get the solution directly.

 

Best Regards,

Cherrry

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

Hi @fleming507

 

Try this calculated table. Assuming your table name is Table1

 

Table =
VAR Temp1 =
    GENERATE (
        Table1,
        VAR mydays =
            CALCULATE (
                VALUES ( Table1[ NumberOfDays] ),
                Table1[ServiceName] = EARLIER ( Table1[ServiceName] )
            )
        VAR adddays =
            (
                INT ( mydays / 7 )
                    + 1
            )
                * 2
        RETURN
            GENERATESERIES ( 1, mydays + adddays )
    )
VAR temp2 =
    ADDCOLUMNS (
        ADDCOLUMNS ( Temp1, "Scheduled Dates", [ScheduledStartDate ] + [Value] - 1 ),
        "WeekDay", WEEKDAY ( [Scheduled Dates], 2 )
    )
VAR temp3 =
    FILTER ( temp2, [WeekDay] < 6 )
VAR temp4 =
    ADDCOLUMNS (
        temp3,
        "RANK", RANKX (
            FILTER ( temp3, [ServiceName] = EARLIER ( [ServiceName] ) ),
            [Scheduled Dates],
            ,
            ASC,
            DENSE
        )
    )
VAR temp5 =
    FILTER ( temp4, [RANK] <= [ NumberOfDays] )
RETURN
    SUMMARIZE ( temp5, [ServiceName], [Scheduled Dates] )

Regards
Zubair

Please try my custom visuals

@fleming507

 

Please see sample file attached as well

 

 


Regards
Zubair

Please try my custom visuals

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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