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

Inserting Rows into a query

Hi there first time here and im hoping for help!

 

I have a query which results in a table of data as below. I get the [value] against a [attribute] value as the source data works in weeks. 

VenueroleAttributeValue
aLeader05/11/201812
aLeader12/11/201810
aLeader19/11/20188

 

 

I need to convert it into daily data eg. insert rows for each day of the week and apply the same [value] for all days that week e.g

VenueroleAttributeValue
aLeader05/11/201812
aLeader06/11/201812
aLeader07/11/201812
aLeader08/11/201812
aLeader09/11/201812
aLeader10/11/201812
aLeader11/11/201812
aLeader12/11/201810
aLeader13/11/201810
aLeader14/11/201810
aLeader15/11/201810
aLeader16/11/201810
aLeader17/11/201810
aLeader18/11/201810
aLeader19/11/20188
aLeader20/11/20188
aLeader21/11/20188

 

any suggestions greatfully received.

Thanks

3 REPLIES 3
v-frfei-msft
Community Support
Community Support

Hi @SteveA ,

Please check the following steps as below.

 

1. Create a calculated column in the fact table.

 

Yearweek = YEAR('Fact'[Attribute])*100+WEEKNUM('Fact'[Attribute])


2. Create a calculated table to get the excepted result.

Table = 
VAR k =
    CALENDARAUTO ()
VAR f =
    ADDCOLUMNS (
        FILTER (
            k,
            (
                YEAR ( [Date] ) * 100
                    + WEEKNUM ( [Date] )
            )
                IN VALUES ( Fact[Yearweek] )
        ),
        "Yw", YEAR ( [Date] ) * 100
            + WEEKNUM ( [Date] )
    )
VAR re =
    ADDCOLUMNS (
        f,
        "role", CALCULATE ( MAX ( 'Fact'[role] ), FILTER ( 'Fact', Fact[Yearweek] = [Yw] ) ),
        "value", CALCULATE (
            MAX ( 'Fact'[Value] ),
            FILTER ( 'Fact', Fact[Yearweek] = [Yw] )
        ),
        "veneue", CALCULATE (
            MAX ( 'Fact'[Venue] ),
            FILTER ( 'Fact', Fact[Yearweek] = [Yw] )
        )
    )
RETURN
    re

Capture.PNG

 

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

Thanks very much

mangaed to copy your solutionSmiley Happy, i've run into trouble though, I have multiple venue types and multiple role types in the table, this seems to confuse the results. I only get one venue, one role bu tthe max of al roles in the value column. Smiley Sad

Do i need to seperate them data out before this step or is there another way to tget he results?

 

thankyou

 

steve

 

Anonymous
Not applicable

Hi @SteveA -

In Power Query, you can do the following steps:

1. If you don't have a Date table, create one. You can use an M script such as the one below.

2. Merge with the Date table (Right Outer Join). 

3. Expand the new column and include the Date column only.

4. Order by the new date column.

5. Fill the values up or down, depending on your requirement.

6. Get rid of the original date column.

M script:

let
    //Set the following variables
    Culture = "English (United States)", //Select a culture.
    UseYesterdayAsCurrentDate = true, //true = yesterday, false = today
    YearsBack = 2, //How many years to include prior to the current year.
    YearsAhead = 2, //How many years to include after the current year.
    GoToBeginning = "Year", //Options: Year, Month, None
    GoToEnd = "Year", //Options: Year, Month, None

    //Figure the Start and End Dates, based on above variables
    DateToday = DateTime.Date(DateTime.LocalNow()),
    CurrentDate = if UseYesterdayAsCurrentDate = true then Date.AddDays(DateToday, -1) else DateToday,
    YearBegin = Date.Year(CurrentDate) - YearsBack,
    MonthBegin = if GoToBeginning = "Year" then 1 else Date.Month(CurrentDate),
    DayBegin = if GoToBeginning = "None" then Date.Day(CurrentDate) else 1,
    StartDate = #date(YearBegin, MonthBegin, DayBegin), 
    YearEnd = Date.Year(CurrentDate) + YearsAhead,
    MonthEnd = if GoToEnd = "Year" then 12 else Date.Month(CurrentDate),
    DayEndTemp = if GoToEnd = "Year" then 31 else Date.Day(CurrentDate),
    EndDateTemp = #date(YearEnd, MonthEnd, DayEndTemp), 
    EndDate = if GoToEnd = "Month" then DateTime.Date(Date.EndOfMonth(EndDateTemp)) else EndDateTemp,
    DayCount = Duration.Days(Duration.From(EndDate - StartDate)) + 1,

    //Get complete list of dates, Convert to a table, update name and data type
    AllDates = List.Dates(StartDate,DayCount,#duration(1,0,0,0)),
    TableFromList = Table.FromList(AllDates, Splitter.SplitByNothing()),
    ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type date}}),
    RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Date"}}),

    //Add other attributes of the date, as desired
    InsertYear = Table.AddColumn(RenamedColumns, "Year", each Date.Year([Date])),
    InsertQuarterOfYear = Table.AddColumn(InsertYear, "Quarter Of Year", each Date.QuarterOfYear([Date])),
    InsertMonthOfYear = Table.AddColumn(InsertQuarterOfYear, "Month Of Year", each Date.Month([Date])),
    InsertDayOfMonth = Table.AddColumn(InsertMonthOfYear, "Day Of Month", each Date.Day([Date])),
    InsertDayOfWeek = Table.AddColumn(InsertDayOfMonth, "Day Of Week", each Date.DayOfWeek([Date])),
    InsertDateAlternateKey = Table.AddColumn(InsertDayOfWeek, "Date Alternate Key", each [Year] * 10000 + [Month Of Year] * 100 + [Day Of Month]),
    InsertMonthName = Table.AddColumn(InsertDateAlternateKey, "Month Name", each Date.ToText([Date], "MMMM", Culture), type text),
    InsertMonthKey = Table.AddColumn(InsertMonthName, "Month Key", each [Year] * 100 + [Month Of Year]),
    InsertMonthYear = Table.AddColumn(InsertMonthKey, "Month Year", each (try(Text.Range([Month Name],0,3)) otherwise [Month Name]) & " " & Number.ToText([Year])),
    InsertQuarterName = Table.AddColumn(InsertMonthYear, "Quarter Name", each "Q" & Number.ToText([Quarter Of Year])),
    InsertQuarterKey = Table.AddColumn(InsertQuarterName, "Quarter Key", each [Year] * 100 + [Quarter Of Year]),
    InsertQuarterYear = Table.AddColumn(InsertQuarterKey, "Quarter Year", each "Q" & Number.ToText([Quarter Of Year]) & " " & Number.ToText([Year])),
    InsertDayName = Table.AddColumn(InsertQuarterYear, "Day Of Week Name", each Date.ToText([Date], "dddd", Culture), type text),
    InsertWeekEnding = Table.AddColumn(InsertDayName, "Week Ending", each Date.EndOfWeek([Date]), type date),

    //Add Relative Date Positions.
    InsertRelativeYear = Table.AddColumn(InsertWeekEnding, "Relative Year", each [Year]-Date.Year(CurrentDate)),
    InsertRelativeYearDescription = Table.AddColumn(InsertRelativeYear, "Relative Year Description", 
                                    each if [Relative Year] = 0 then "Current Year"
                                        else if [Relative Year] = -1 then "Last Year"
                                        else if [Relative Year] = 1 then "Next Year"
                                        else if [Relative Year] < -1 then Number.ToText(Number.Abs([Relative Year])) & " Years Back" 
                                        else Number.ToText([Relative Year]) & " Years Ahead"),
    InsertRelativeQuarter = Table.AddColumn(InsertRelativeYearDescription, "Relative Quarter", 
                                    each 4*([Year]-Date.Year(CurrentDate)) + ([Quarter Of Year]-Date.QuarterOfYear(CurrentDate))),
    InsertRelativeQuarterDescription = Table.AddColumn(InsertRelativeQuarter, "Relative Quarter Description", 
                                    each if [Relative Quarter] = 0 then "Current Quarter"
                                        else if [Relative Quarter] = -1 then "Last Quarter"
                                        else if [Relative Quarter] = 1 then "Next Quarter"
                                        else if [Relative Quarter] < -1 then Number.ToText(Number.Abs([Relative Quarter])) & " Quarters Back" 
                                        else Number.ToText([Relative Quarter]) & " Quarters Ahead"),
    InsertRelativeMonth = Table.AddColumn(InsertRelativeQuarterDescription, "Relative Month", 
                                    each 12*([Year]-Date.Year(CurrentDate)) + ([Month Of Year]-Date.Month(CurrentDate))),
    InsertRelativeMonthDescription = Table.AddColumn(InsertRelativeMonth, "Relative Month Description", 
                                    each if [Relative Month] = 0 then "Current Month"
                                        else if [Relative Month] = -1 then "Last Month"
                                        else if [Relative Month] = 1 then "Next Month"
                                        else if [Relative Month] < -1 then Number.ToText(Number.Abs([Relative Month])) & " Months Back" 
                                        else Number.ToText([Relative Month]) & " Months Ahead"),
    InsertRelativeWeek = Table.AddColumn(InsertRelativeMonthDescription, "Relative Week", 
                                    each Duration.Days(Duration.From([Week Ending]-Date.EndOfWeek(CurrentDate)))/7),
    InsertRelativeWeekDescription = Table.AddColumn(InsertRelativeWeek, "Relative Week Description", 
                                    each if [Relative Week] = 0 then "Current Week"
                                        else if [Relative Week] = -1 then "Last Week"
                                        else if [Relative Week] = 1 then "Next Week"
                                        else if [Relative Week] < -1 then Number.ToText(Number.Abs([Relative Week])) & " Weeks Back" 
                                        else Number.ToText([Relative Week]) & " Weeks Ahead"),
    InsertRelativeDay = Table.AddColumn(InsertRelativeWeekDescription, "Relative Day", 
                                    each Duration.Days(Duration.From([Date]-CurrentDate))),
    InsertRelativeDayDescription = Table.AddColumn(InsertRelativeDay, "Relative Day Description", 
                                    each if [Relative Day] = 0 then "Current Day"
                                        else if [Relative Day] = -1 then "Last Day"
                                        else if [Relative Day] = 1 then "Next Day"
                                        else if [Relative Day] < -1 then Number.ToText(Number.Abs([Relative Day])) & " Days Back" 
                                        else Number.ToText([Relative Day]) & " Days Ahead"),

    //Add Date Category Positions.
    InsertYearGroup = Table.AddColumn(InsertRelativeDayDescription, "Year Group", 
                                    each if [Relative Year] = 0 then "Current Year"
                                        else if [Relative Year] < 0 then "Past Years"
                                        else "Future Years"),
    InsertQuarterGroup = Table.AddColumn(InsertYearGroup, "Quarter Group", 
                                    each if [Relative Quarter] = 0 then "Current Quarter"
                                        else if [Relative Quarter] < 0 then "Past Quarters"
                                        else "Future Quarters"),
    InsertMonthGroup = Table.AddColumn(InsertQuarterGroup, "Month Group", 
                                    each if [Relative Month] = 0 then "Current Month"
                                        else if [Relative Month] < 0 then "Past Months"
                                        else "Future Months"),
    InsertWeekGroup = Table.AddColumn(InsertMonthGroup, "Week Group", 
                                    each if [Relative Week] = 0 then "Current Week"
                                        else if [Relative Week] < 0 then "Past Weeks"
                                        else "Future Weeks"),
    InsertDayGroup = Table.AddColumn(InsertWeekGroup, "Day Group", 
                                    each if [Relative Day] = 0 then "Current Day"
                                        else if [Relative Day] < 0 then "Past Days"
                                        else "Future Days"),
    #"Changed Type" = Table.TransformColumnTypes(InsertDayGroup,{{"Year", Int64.Type}, {"Quarter Of Year", Int64.Type}, {"Month Of Year", Int64.Type}, {"Day Of Month", Int64.Type}, {"Day Of Week", Int64.Type}, {"Date Alternate Key", Int64.Type}, {"Quarter Name", type text}, {"Month Year", type text}, {"Quarter Year", type text}, {"Relative Year Description", type text}, {"Relative Quarter Description", type text}, {"Relative Month Description", type text}, {"Relative Week Description", type text}, {"Relative Day Description", type text}, {"Year Group", type text}, {"Quarter Group", type text}, {"Month Group", type text}, {"Week Group", type text}, {"Day Group", type text}, {"Relative Day", Int64.Type}, {"Relative Week", Int64.Type}, {"Relative Month", Int64.Type}, {"Relative Quarter", Int64.Type}, {"Relative Year", Int64.Type}, {"Quarter Key", Int64.Type}, {"Month Key", Int64.Type}}),

    //Add Date In Fact Table Attributes.
    maxSales = Date.AddDays(DateToday, -1) //List.Max(Table.Column(Sales, "SalesDate")),
    InsertHasSalesData = Table.AddColumn(#"Changed Type", "Has Sales Data", 
                                    each if [Date] <= maxSales  then "Yes"
                                        else "No"),
    InsertHasSalesDataCompleteMonth = Table.AddColumn(InsertHasSalesData, "Has Sales Data Complete Month", 
                                    each if Date.EndOfMonth([Date]) <= maxSales then "Yes"
                                        else "No")
in
    InsertHasSalesDataCompleteMonth

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.