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

Prepping for a Fabric certification exam? Join us for a live prep session with exam experts to learn how to pass the exam. Register now.

Reply
RobX
Advocate I
Advocate I

Fill in Missing Dates

I have a table of weekly values that I want to break out into daily values.

 

Data is similar to below but is in Excel.

 

 

CREATE TABLE #tempTable (
Brand VARCHAR(100),
Date DATE,
Spend int)

INSERT INTO #tempTable
(
    Brand,
    Date,
    Spend
)
VALUES 
('A', '1/7/2021', 100),
('A',  '1/14/2021', 150),
('A', '1/21/2021', 200),
('B', '1/7/2021', 250),
('B', '1/14/2021', 200),
('B', '1/21/2021', 900),
('C', '1/7/2021', 200),
('C', '1/14/2021', 100),
('C', '1/21/2021', 50)

SELECT
	*
FROM #tempTable

 

 

 

I want to generate records for every day in between the available dates for each Brand so that the end result looks like this:

RobX_0-1626803148908.png

 

I found this suggestion on in an old StackOverflow post, but it only works to create a table with just Date and Spend.

FullTable = 
ADDCOLUMNS(
    CALENDAR(MIN(#tempTable[Date]), MAX(#tempTable[Date])),
    "Quantity",
    LOOKUPVALUE(
        #tempTable[Spend],
        #tempTable[Date],
        MAXX(
            FILTER(#tempTable, #tempTable[Date] <= EARLIER([Date])),
            [Date]
        )
    )
)

 

Does anyone have any idea how to expand it to include an additional dimension?

1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

 

let
    Source = #table({"Brand","Date","Spend"},{
        {"A", "1/7/2021", 100},
        {"A",  "1/14/2021", 150},
        {"A", "1/21/2021", 200},
        {"B", "1/7/2021", 250},
        {"B", "1/14/2021", 200},
        {"B", "1/21/2021", 900},
        {"C", "1/7/2021", 200},
        {"C", "1/14/2021", 100},
        {"C", "1/21/2021", 50}}),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}}),
    #"Transformed Column" = Table.TransformColumns(#"Changed Type", {"Date", each List.Reverse(List.Dates(_,7,-#duration(1,0,0,0)))}),
    #"Expanded Date" = Table.ExpandListColumn(#"Transformed Column", "Date")
in
    #"Expanded Date"

 

Screenshot 2021-07-20 224443.png

 

 

Expansion_DAX = 
GENERATE (
    Base,
    ADDCOLUMNS ( GENERATESERIES ( 0, 6 ), "All Date", Base[Date] - [Value] )
)

Screenshot 2021-07-20 232404.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

2 REPLIES 2
CNENFRNL
Community Champion
Community Champion

 

let
    Source = #table({"Brand","Date","Spend"},{
        {"A", "1/7/2021", 100},
        {"A",  "1/14/2021", 150},
        {"A", "1/21/2021", 200},
        {"B", "1/7/2021", 250},
        {"B", "1/14/2021", 200},
        {"B", "1/21/2021", 900},
        {"C", "1/7/2021", 200},
        {"C", "1/14/2021", 100},
        {"C", "1/21/2021", 50}}),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}}),
    #"Transformed Column" = Table.TransformColumns(#"Changed Type", {"Date", each List.Reverse(List.Dates(_,7,-#duration(1,0,0,0)))}),
    #"Expanded Date" = Table.ExpandListColumn(#"Transformed Column", "Date")
in
    #"Expanded Date"

 

Screenshot 2021-07-20 224443.png

 

 

Expansion_DAX = 
GENERATE (
    Base,
    ADDCOLUMNS ( GENERATESERIES ( 0, 6 ), "All Date", Base[Date] - [Value] )
)

Screenshot 2021-07-20 232404.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

The DAX example was exactly what I needed.  Though one of the dates did get duplicated, but I'll find a way around that.

 

Thanks!

Helpful resources

Announcements
PBIApril_Carousel

Power BI Monthly Update - April 2025

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

Notebook Gallery Carousel1

NEW! Community Notebooks Gallery

Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.

April2025 Carousel

Fabric Community Update - April 2025

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