skip to main content
Power BI
    • What is Power BI
    • Why Power BI
    • Customer stories
    • Data visuals
    • Security
    • Power BI Desktop
    • Power BI Pro
    • Power BI Premium
    • Power BI Mobile
    • Power BI Embedded
    • Power BI Report Server
  • Pricing
    • Azure + Power BI
    • Microsoft 365 + Power BI
    • Dynamics 365 + Power BI
      • Energy
      • Healthcare
      • Manufacturing
      • Media
      • Retail
    • For analysts
    • For IT
      • Overview
      • Embedded analytics
      • Power BI visuals
      • Automation
      • Documentation
      • Community
    • Partners Overview
    • Solutions Partners
    • BI Specialized Partners
    • Power BI CSOs
    • Fabric Partner Community
    • Training
    • Getting started
      • Overview
      • Self-guided learning
      • Webinars
      • Documentation
      • Roadmap
      • Overview
      • Issues
      • Give feedback
    • Blog
    • Business intelligence topics
    • Overview
    • Forums
    • Galleries
    • Submit ideas
    • Events
    • User groups
    • Community blog
    • Register
    • ·
    • Sign in
    • ·
    • Help
    Go To
    • Power BI forums
    • Updates
    • News & Announcements
    • Get Help with Power BI
    • Desktop
    • Service
    • Report Server
    • Power Query
    • Mobile Apps
    • Developer
    • DAX Commands and Tips
    • Custom Visuals Development Discussion
    • Health and Life Sciences
    • Power BI Spanish forums
    • Translated Spanish Desktop
    • Power Platform Integration - Better Together!
    • Power Platform Integrations
    • Power Platform and Dynamics 365 Integrations
    • Training and Consulting
    • Instructor Led Training
    • Galleries
    • Community Connections & How-To Videos
    • COVID-19 Data Stories Gallery
    • Themes Gallery
    • Data Stories Gallery
    • R Script Showcase
    • Webinars and Video Gallery
    • Quick Measures Gallery
    • 2021 MSBizAppsSummit Gallery
    • 2020 MSBizAppsSummit Gallery
    • 2019 MSBizAppsSummit Gallery
    • Events
    • Ideas
    • Custom Visuals Ideas
    • Issues
    • Issues
    • Events
    • Upcoming Events
    • Community Engagement
    • T-Shirt Design Challenge 2023
    • Community Blog
    • Power BI Community Blog
    • Custom Visuals Community Blog
    • Community Support
    • Community Accounts & Registration
    • Using the Community
    • Community Feedback
    cancel
    Turn on suggestions
    Auto-suggest helps you quickly narrow down your search results by suggesting possible matches as you type.
    Showing results for 
    Search instead for 
    Did you mean: 

    Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

    • Power BI forums
    • Galleries
    • Quick Measures Gallery
    • Calendar that starts with any Date of the Month - ...

    Calendar that starts with any Date of the Month - Just two variables apart

    05-19-2022 03:37 AM

    Super User amitchandak
    Super User
    388 Views
    LinkedIn LinkedIn Facebook Facebook Twitter Twitter
    amitchandak
    Super User amitchandak
    Super User
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    Calendar that starts with any Date of the Month - Just two variables apart

    ‎05-19-2022 03:37 AM

    Calendar that starts with any Date of the Month - Just two variables apart

    Power BI(101).png

     

    Objective:

    To have a calendar for any date of the month by just changing only two variables, the end month and end date

     

    Solution:

    The solution should use the month and date as a variable and should create a calendar whose start and end date are based on the end month and date provided.
    The calendar should generate the month start date, month end date, FY month number, quarter start Date, quarter end Date, and FY week

     

    I created a script. For the calendar start date, I have logic using the year 2018. For the calendar end date, I simply try to reach the end date using the standard calendar end date and today, so you might see a few years have one additional year of data
    There are a few tables generated using addcolumns. I tried to minimize the formula's repetition.
    Variable are 


    _FYENDMonth - Provide the month in which the calendar will have an end date
    _date provide the end day/date of the month

     

    Date = var _max = Today() 
    var _FYENDMonth =5
    var _date = 15
    var _MMDD = _FYENDMonth *100 + _Date 
    var _FYRemain = 12 -_FYENDMonth
    var _end = EOMONTH(_max,12-MONTH(_max)+_FYENDMonth)+_date
    
    var _cal =  
    ADDCOLUMNS( CALENDAR(DATE(2018,_FYENDMonth,_date+1), _end) 
        , "Month Year" , FORMAT([Date], "MMM-YYYY")
        , "Month year Sort" , Year([Date])*100 + month([date])
        , "month start date" , if(day([Date])<=_date, EOMONTH([Date],-2)+_date ,EOMONTH([Date],-1)+_date )+1
        , "month end date" , if(day([Date])<=_date, EOMONTH([Date],-1)+_date ,EOMONTH([Date],0)+_date )
        , "FY year Start Date", if(format([Date], "MMDD")*1<=_MMDD, date(Year([Date])-1,_FYENDMonth,_date) ,date(Year([Date]),_FYENDMonth,_date)) +1
        , "FY year End Date", if(format([Date], "MMDD")*1<=_MMDD, date(Year([Date]),_FYENDMonth,_date) ,date(Year([Date])+1,_FYENDMonth,_date)) 
        ,"Weekday name", format([date], "dddd")
        , "Weekday", WEEKDAY([Date],2)
        ,"Start Week Date" , [Date] -1* WEEKDAY([Date],2) +1
        ,"End Week Date" , [Date] + 7 -1* WEEKDAY([Date],2) 
        , "Cal Year",year([date]))
    Var _cal_cal2 =AddColumns( _cal,
        "FY" , Year([FY year Start Date]),
        "FY Month" , Datediff([FY year Start Date], [month start date],MONTH)+1 ,
        "FY Qtr" , Quotient(Datediff([FY year Start Date], [month start date],MONTH),3)+1 ,
        "FY Qtr Start" , Eomonth([FY year Start Date],Quotient(Datediff([FY year Start Date], [month start date],MONTH),3)*3-1)+1+_date ,
        "FY Qtr End" , Eomonth([FY year Start Date],Quotient(Datediff([FY year Start Date], [month start date],MONTH),3)*3+2)+_date ,
        "FY Week Start",[FY year Start Date] -WEEKDAY([FY year Start Date],2)+1
    )
    //var _end = ENDOFYEAR(Sales[Sales Date]) 
    return 
    ADDCOLUMNS(_cal_cal2,
    "FY Year Month" , [FY]*100 + [FY Month]
    ,"FY Year Qtr" , [FY]*100 + [FY Qtr]
    ,"FY Qtr Year" , "Q" & [FY Qtr] & "-" &[FY]
    ,"FY Week" , QUOTIENT(DATEDIFF([FY Week Start],[Date],day),7)+1
    ,"FY Week No" , [FY]*100 + QUOTIENT(DATEDIFF([FY Week Start],[Date],day),7)+1
    
    )

     

    Click Here to access all my blogs and videos in a jiffy via an exclusive visual glossary using Power BI.
    Please like, share, and comment on these. Your suggestions on improvement, challenges, and new topics will help me explore more.

    You Can watch my Power BI Tutorial Series on My Channel, Subscribe, Like, and share



    !! Power BI 101 Interview questions !! !! Master Microsoft Fabric- 36 Videos !!
    Microsoft Power BI Learning Resources, 2023 !!
    Learn Power BI - Full Course with Dec-2022, with Window, Index, Offset, 100+ Topics !!
    Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
    One Variable All Calendar Any Date.pbix
    Labels:
    • Labels:
    • Financial
    • Mathematical
    • Time Intelligence
    Message 1 of 1
    388 Views
    0
    Reply
    • All forum topics
    • Previous Topic
    • Next Topic

    Power Platform

    • Overview
    • Power BI
    • Power Apps
    • Power Pages
    • Power Automate
    • Power Virtual Agents

    • Sign in
    • Sign up

    Browse

    • Solutions
    • Partners
    • Consulting Services

    Downloads

    • Power BI Desktop
    • Power BI Mobile
    • Power BI Report Server
    • See all downloads

    Learn

    • Guided learning
    • Documentation
    • Support
    • Community
    • Give feedback
    • Webinars
    • Developers
    • Blog
    • Newsletter

    © 2023 Microsoft

    Follow Power BI

    • Privacy & cookies
    • Manage cookies
    • Terms of use
    • Trademarks
    Consumer Privacy Act (CCPA) Opt-Out Icon Your Privacy Choices