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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
Ruslan_Baranov
Frequent Visitor

How to add rows with missing dates

Hello everyone.
Need help with a table. There is a table with exchange rates.

Ruslan_Baranov_2-1741269523854.png

 

Question 1: How to add rows between missing dates
For example, I need to add dates between 28/02/2025 and 03/03/2025, data for 28/02/2025 should be for missing dates. see the picture

Ruslan_Baranov_3-1741269556170.png

 

Question 2: How to shift data one forward?

Thanks in advance

1 ACCEPTED SOLUTION
v-denglli-msft
Community Support
Community Support

Hi @Ruslan_Baranov , 

 

After loading the table in the Power Query editor and adding a new query, use the following M code to reference the source table to create a new table that meets the requirements.

let
  StartDate = List.Min(Table[Date from original report]),
  EndDate = List.Max(Table[Date from original report]),
  DateList = List.Dates(StartDate, Duration.Days(EndDate - StartDate) + 1, #duration(1, 0, 0, 0)),
  DateTable = Table.TransformColumnTypes(
    Table.FromList(
      DateList,
      Splitter.SplitByNothing(),
      {"Date from original report"},
      null,
      ExtraValues.Error
    ),
    {{"Date from original report", type date}}
  ),
  #"Merged Queries" = Table.NestedJoin(
    DateTable,
    {"Date from original report"},
    Table,
    {"Date from original report"},
    "Table",
    JoinKind.LeftOuter
  ),
  #"Expanded Table" = Table.Sort(
    Table.ExpandTableColumn(#"Merged Queries", "Table", {"ExRate"}, {"ExRate"}),
    {{"Date from original report", Order.Ascending}}
  ),
  #"Filled Down" = Table.FillDown(#"Expanded Table", {"ExRate"}),
  #"Added Custom" = Table.AddColumn(
    #"Filled Down",
    "Date from final report",
    each [Date from original report] + #duration(1, 0, 0, 0)
  ),
  #"Changed Type" = Table.TransformColumnTypes(
    #"Added Custom",
    {{"Date from final report", type date}}
  ),
  #"Reordered Columns" = Table.ReorderColumns(
    #"Changed Type",
    {"Date from original report", "Date from final report", "ExRate"}
  )
in
  #"Reordered Columns"

vdengllimsft_0-1741316780503.png

 

The approximate steps are as follows:

First generate a date table containing the desired date range.

vdengllimsft_6-1741315667647.png

 

Then merge the date table with the source data table using the left join.

vdengllimsft_7-1741315695597.png

 

Select the 'ExRate' column and use the fill down.

vdengllimsft_8-1741315714783.png

 

Add a custom column that shows the date moved forward one day.

vdengllimsft_9-1741315755125.png

 

 

 

Please see the attached pbix for reference.

 

Best Regards,
Dengliang Li

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

5 REPLIES 5
sanalytics
Super User
Super User

Hello @Ruslan_Baranov 
You can follow below M code as well

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XcjJCcAwDATAXvZthUXO+qhFqP82EtAjxDCviYAvo5vThQZe0hSyBdjt9f3gqr//r9nrdX71OHpvZD4=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date from original report" = _t, ExRate = _t]),
    #"Added Index" = Table.AddIndexColumn(Source, "FirstIndex", 1
, 1, Int64.Type),
    #"Added Index1" = Table.AddIndexColumn(#"Added Index", "SecondIndex", 0, 1, Int64.Type),
    #"Merged Queries" = Table.NestedJoin(#"Added Index1", {"FirstIndex"}, #"Added Index1", {"SecondIndex"}, "Added Index1", JoinKind.LeftOuter),
    #"Expanded Added Index1" = Table.ExpandTableColumn(#"Merged Queries", "Added Index1", {"Date from original report"}, {"EndDate"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Added Index1",{{"SecondIndex", Order.Ascending}}),
    #"Filled Down" = Table.FillDown(#"Sorted Rows",{"EndDate"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Filled Down",{{"EndDate", type date},{"Date from original report",type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "ListOfDate", each List.Dates(
    [Date from original report],
Number.From([EndDate] ) - Number.From( [Date from original report] ) ,
#duration(1,0,0,0)
)),
    #"Expanded ListOfDate" = Table.ExpandListColumn(#"Added Custom", "ListOfDate"),
    #"Added Conditional Column" = Table.AddColumn(#"Expanded ListOfDate", "OriginalDate", each if [ListOfDate] = null then [Date from original report] else [ListOfDate]),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Conditional Column",{"ExRate", "OriginalDate"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Other Columns",{"OriginalDate", "ExRate"})
in
    #"Reordered Columns"

 

Below screenshot

sanalytics_0-1741339271645.png

Hope it will help

 

Regards

sanalytics

Thanks for your help, I haven't tried your method, I used the previous one, but I'm sure yours works too

v-denglli-msft
Community Support
Community Support

Hi @Ruslan_Baranov , 

 

After loading the table in the Power Query editor and adding a new query, use the following M code to reference the source table to create a new table that meets the requirements.

let
  StartDate = List.Min(Table[Date from original report]),
  EndDate = List.Max(Table[Date from original report]),
  DateList = List.Dates(StartDate, Duration.Days(EndDate - StartDate) + 1, #duration(1, 0, 0, 0)),
  DateTable = Table.TransformColumnTypes(
    Table.FromList(
      DateList,
      Splitter.SplitByNothing(),
      {"Date from original report"},
      null,
      ExtraValues.Error
    ),
    {{"Date from original report", type date}}
  ),
  #"Merged Queries" = Table.NestedJoin(
    DateTable,
    {"Date from original report"},
    Table,
    {"Date from original report"},
    "Table",
    JoinKind.LeftOuter
  ),
  #"Expanded Table" = Table.Sort(
    Table.ExpandTableColumn(#"Merged Queries", "Table", {"ExRate"}, {"ExRate"}),
    {{"Date from original report", Order.Ascending}}
  ),
  #"Filled Down" = Table.FillDown(#"Expanded Table", {"ExRate"}),
  #"Added Custom" = Table.AddColumn(
    #"Filled Down",
    "Date from final report",
    each [Date from original report] + #duration(1, 0, 0, 0)
  ),
  #"Changed Type" = Table.TransformColumnTypes(
    #"Added Custom",
    {{"Date from final report", type date}}
  ),
  #"Reordered Columns" = Table.ReorderColumns(
    #"Changed Type",
    {"Date from original report", "Date from final report", "ExRate"}
  )
in
  #"Reordered Columns"

vdengllimsft_0-1741316780503.png

 

The approximate steps are as follows:

First generate a date table containing the desired date range.

vdengllimsft_6-1741315667647.png

 

Then merge the date table with the source data table using the left join.

vdengllimsft_7-1741315695597.png

 

Select the 'ExRate' column and use the fill down.

vdengllimsft_8-1741315714783.png

 

Add a custom column that shows the date moved forward one day.

vdengllimsft_9-1741315755125.png

 

 

 

Please see the attached pbix for reference.

 

Best Regards,
Dengliang Li

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

Thank you a lot, it's working

Ruslan_Baranov
Frequent Visitor

Screenshot of the table for the second question

Ruslan_Baranov_0-1741270001943.png

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

Feb2025 NL Carousel

Fabric Community Update - February 2025

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