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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.

Reply
Felipekard
Frequent Visitor

Repeat rows until next day

Hi guys, can you help me?

I has this table:

COUNTRYDATEVALUE
BRAZIL09/20/202310
BRAZIL09/21/202310
BRAZIL09/22/202310
CANADA09/20/202310
CANADA09/23/202320
CANADA09/25/202330

 

And Brazil is daily, but canada only have some days.

 

I need made canada daily, repeat the next days with the value of last days, create the red rows below.

 

my table need be like this:

 

COUNTRYDATEVALUE
BRAZIL09/20/202310
BRAZIL09/21/202310
BRAZIL09/22/202310
CANADA09/20/202310
CANADA09/21/202310
CANADA09/22/202310
CANADA09/23/202320
CANADA09/24/202320
CANADA09/25/202330
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Felipekard 

You can create two blank queries in power query 

then put the following code to advanced editor

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcgpyjPL0UdJRMrDUNzIAIiNjIMfQQClWB03SEJ+kEZqks6Ofo4sjDmNRJI1hkkZYJE1hksZAyVgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [COUNTRY = _t, DATE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"COUNTRY", type text}, {"DATE", type date}, {"VALUE", Int64.Type}})
in
    #"Changed Type"
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcgpyjPL0UdJRMrDUNzIAIiNjIMfQQClWB03SEJ+kEZqks6Ofo4sjDmNRJI1hkkZYJE1hksZAyVgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [COUNTRY = _t, DATE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"COUNTRY", type text}, {"DATE", type date}, {"VALUE", Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"COUNTRY", Order.Ascending}, {"DATE", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"COUNTRY"}, {{"min", each List.Min([DATE])},{"max",each List.Max([DATE])}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each List.Dates([min],Duration.Days([max]-[min])+1,#duration(1,0,0,0))),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"min", "max"}),
    #"Merged Queries" = Table.NestedJoin(#"Removed Columns", {"COUNTRY", "Custom"}, #"Query1", {"COUNTRY", "DATE"}, "Table (2)", JoinKind.LeftOuter),
    #"Expanded Table (2)" = Table.ExpandTableColumn(#"Merged Queries", "Table (2)", {"VALUE"}, {"VALUE"}),
    #"Filled Down" = Table.FillDown(#"Expanded Table (2)",{"VALUE"})
in
    #"Filled Down"

Output

vxinruzhumsft_0-1695368909449.png

Best Regards!

Yolo Zhu

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

2 REPLIES 2
Anonymous
Not applicable

Hi @Felipekard 

You can create two blank queries in power query 

then put the following code to advanced editor

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcgpyjPL0UdJRMrDUNzIAIiNjIMfQQClWB03SEJ+kEZqks6Ofo4sjDmNRJI1hkkZYJE1hksZAyVgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [COUNTRY = _t, DATE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"COUNTRY", type text}, {"DATE", type date}, {"VALUE", Int64.Type}})
in
    #"Changed Type"
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcgpyjPL0UdJRMrDUNzIAIiNjIMfQQClWB03SEJ+kEZqks6Ofo4sjDmNRJI1hkkZYJE1hksZAyVgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [COUNTRY = _t, DATE = _t, VALUE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"COUNTRY", type text}, {"DATE", type date}, {"VALUE", Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"COUNTRY", Order.Ascending}, {"DATE", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"COUNTRY"}, {{"min", each List.Min([DATE])},{"max",each List.Max([DATE])}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each List.Dates([min],Duration.Days([max]-[min])+1,#duration(1,0,0,0))),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"min", "max"}),
    #"Merged Queries" = Table.NestedJoin(#"Removed Columns", {"COUNTRY", "Custom"}, #"Query1", {"COUNTRY", "DATE"}, "Table (2)", JoinKind.LeftOuter),
    #"Expanded Table (2)" = Table.ExpandTableColumn(#"Merged Queries", "Table (2)", {"VALUE"}, {"VALUE"}),
    #"Filled Down" = Table.FillDown(#"Expanded Table (2)",{"VALUE"})
in
    #"Filled Down"

Output

vxinruzhumsft_0-1695368909449.png

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

slorin
Super User
Super User

Hi,

 

let
Source = YourSource,
#"Grouped Rows" = Table.Group(Source, {"COUNTRY"},
{{"DATE", each List.Dates(List.Min([DATE]), Duration.Days(List.Max([DATE])-List.Min([DATE]))+1, #duration(1,0,0,0))}}),
#"Expanded {0}" = Table.ExpandListColumn(#"Grouped Rows", "DATE"),
#"Merged Queries" = Table.NestedJoin(#"Expanded {0}", {"COUNTRY", "DATE"}, Source, {"COUNTRY", "DATE"}, "Expanded {0}", JoinKind.LeftOuter),
#"Expanded {0}1" = Table.ExpandTableColumn(#"Merged Queries", "Expanded {0}", {"VALUE"}, {"VALUE"}),
#"Filled Down" = Table.FillDown(#"Expanded {0}1",{"VALUE"})
in
#"Filled Down"

Stéphane 

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors
Top Kudoed Authors