Custom Column to detect # of Days in Column Headings with Dates

programsam

Board Regular
Joined
Feb 10, 2016
Messages
123
Similar to a question below, I'm trying to:
  1. detect columns with dates in the header
  2. look at the most recent 3 months (this is dynamic as a new month is added every month)
  3. calculates the # of days within the prior 3 months
  4. calculates the average number of units per day in the prior 3 months.
As example

1691099282658.png
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Since there were no takers, I think maybe I need to update the question. Visually, here's what I'm trying to accomplish.

1691159998537.png
 
Upvote 0
The update still doesn't explain more about what you are looking for compared to the list in the original question.
Note: If this is a question related to another question that you posted and received an answer to, then you should better provide a link to that thread, so we can take a look at it.

However, this is what I can guess from the existing material and the description so far.
You have the following data:
1691238168770-png.96605


And you want to convert it to the following:
1691238210777.png

Where the months before the current month will show the daily units according to the day count in the associated month. For example, 50/30 = 1.666 for April 2023. The current month will show the original value.

As a model, this doesn't make any sense to me, so I didn't even analyze the "prior 3 months" part yet, but this is what I can guess so far.

The code that transforms the data as shown above is:
Power Query:
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI1ABImliDCGEgYgwgjA6VYnWglJyDTDCRtbABjmUC5IGlnGN8IWQbMAkm7wPhgwtwAZheQiI0FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Product = _t, #"April 2023" = _t, #"May 2023" = _t, #"June 2023" = _t, #"July 2023" = _t, #"August 2023" = _t]),
    Result = Table.FromRecords(Table.TransformRows(Source,
    (r) => Record.TransformFields(r, 
        List.Transform(Record.FieldNames(r), each {_, (i) => try if Date.IsInCurrentMonth(Date.From(_)) then i else Number.From(i) / Date.DaysInMonth(Date.From(_)) otherwise i}))))
in
    Result

I am aware this might not be the desired result, but perhaps you can provide more information by looking at how I explained the source and result above.
 

Attachments

  • 1691238168770.png
    1691238168770.png
    42.9 KB · Views: 15
Upvote 0

Forum statistics

Threads
1,216,731
Messages
6,132,391
Members
449,725
Latest member
Enero1

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top