Date format changes when adding subtotals

JeffGrant

Well-known Member
Joined
Apr 7, 2021
Messages
510
Office Version
  1. 365
Platform
  1. Windows
Hi all,

In Australia we use a date format of dd/mm/yyyy as one style that I use.

Using VBA, I use the DATE() function to add a date to rows and it correctly picks up the local date format of dd/mm/yyyy. No Problem.

However, when I add Sub-Totals, the Sub-Total Label as "mm/dd/yyyy Total" like this

1642678457314.png


and I don't know why.

Being upsidedown to the rest of the world, I really would prefer having the Sub Total labels in our format.

Any and all suggestions are greatly welcomed.
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
Bit of a thread resurrection here, it's Interesting that you never got an answer to this, as I am having exactly the same issue.
UK based, so expect dates to be dd/mm/yyyy.

I create a Excel report in VBA from a MS Access database but the subtotal dates are incorrectly formatted:

1689675278449.png


As you can see the core dates are formatted correctly.
If I take the raw data before the subtotals are inserted and put the subtotals in manually within Excel all is good.

I cannot find any solution on the web, does anyone have any clues?
 
Upvote 0
No 'solution' from me but a possible work-around.

My sample data:

Minty.xlsm
BC
1DateAmt
210/05/20231
310/05/20232
410/05/20233
510/05/20234
610/05/20235
710/05/20236
810/05/20237
910/05/20238
1010/05/20239
1110/05/202310
1211/05/202311
1311/05/202312
Sheet3


Code:
VBA Code:
Sub FixSubTotalDates()
    With Range("B1", Range("C" & Rows.Count).End(xlUp))
      .Columns(1).Value = Evaluate(Replace("iferror(text(#,"",dd/mm/yyyy""),#)", "#", .Columns(1).Address))
      .Subtotal GroupBy:=1, Function:=xlSum, TotalList:=Array(2)
    End With
    With Range("B2", Range("B" & Rows.Count).End(xlUp).Offset(-1))
      .TextToColumns DataType:=xlDelimited, Comma:=True, Space:=False, Other:=False, FieldInfo:=Array(Array(1, 9), Array(2, 4))
    End With
End Sub

Result:

Minty.xlsm
BC
1DateAmt
210/05/20231
310/05/20232
410/05/20233
510/05/20234
610/05/20235
710/05/20236
810/05/20237
910/05/20238
1010/05/20239
1110/05/202310
1210/05/2023 Total55
1311/05/202311
1411/05/202312
1511/05/2023 Total23
16Grand Total78
Sheet3
Cell Formulas
RangeFormula
C12C12=SUBTOTAL(9,C2:C11)
C15C15=SUBTOTAL(9,C13:C14)
C16C16=SUBTOTAL(9,C2:C14)
 
Upvote 0
Hi Peter,

That looks promising, although not sure my limited Excel skills fully understand the ninja manoeuvring in the TextToColumns part...
I'll try it later today and return to you, as it's embedded in a mountain of other code.

Many thanks for your quick response.
 
Upvote 0
That looks promising, although not sure my limited Excel skills fully understand the ninja manoeuvring in the TextToColumns part...
I'll try it later today and return to you ..
Cheers. (y)
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,211
Members
448,554
Latest member
Gleisner2

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