Number Format on multiple Ranges

Siyanna

Well-known Member
Joined
Nov 7, 2011
Messages
1,146
Hi Lovely people,

How can i amend this to change the format to multiple ranges selected

the below code aint working but i gave it a shot i gues :)

Code:
Ws.Range("D" & LastWsRow + 1,"F" & LastWsRow + 1,"H" & LastWsRow + 1,"J" & LastWsRow + 1,"L" & LastWsRow + 1,"N" & LastWsRow + 1 _
       "P" & LastWsRow + 1,"R" & LastWsRow + 1,"T" & LastWsRow + 1,"V" & LastWsRow + 1,"X" & LastWsRow + 1,"Z" & LastWsRow + 1,"AB" & LastWsRow + 1 _
       "AD" & LastWsRow + 1, "AF" & LastWsRow + 1,"AH" & LastWsRow + 1.NumberFormat = "$#,##0.00"
 

Some videos you may like

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.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
11,934
Office Version
  1. 365
Platform
  1. Windows
I don't think you can define non-contiguous ranges in that way, with my limited knowledge of vba I would go with something like

Code:
Dim mCol As Long
For mCol = 4 To 34 Step 2
    ws.Cells(LastWsRow + 1, mCol).NumberFormat = "$#,##0.00"
Next

But I expect there are better ways.
 

hippiehacker

Well-known Member
Joined
Aug 2, 2011
Messages
1,911
don't know if better but its working

Code:
Dim MyArray()
Dim X
Dim c As String

MyArray = Array("A", "B", "C", "E") ' change the array to the columns you want

For X = 0 To UBound(MyArray) ' determine lenght of array and how long to loop

c = MyArray(X)
 Sheets("Sheet1").Range(c & "1" & ":" & c & Range(c & Rows.Count).End(xlUp).Row).NumberFormat = "\$#.##000"
Next X
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,378
Yet another method.

Code:
Range("D1, F1, H1, J1, L1, N1, P1, R1, T1, V1, X1, Z1, AB1, AD1, AF1, AH1").Offset(LastWsRow).NumberFormat = "$#,##0.00"
 

Siyanna

Well-known Member
Joined
Nov 7, 2011
Messages
1,146

ADVERTISEMENT

Thank You all

You guys are awesome
 

Siyanna

Well-known Member
Joined
Nov 7, 2011
Messages
1,146
Yet another method.

Code:
Range("D1, F1, H1, J1, L1, N1, P1, R1, T1, V1, X1, Z1, AB1, AD1, AF1, AH1").Offset(LastWsRow).NumberFormat = "$#,##0.00"


Hi AlphaFrog,

I have tried to add more ranges but for some reason it bugs out. Am i missing something

Code:
With .Range("E5:E10,G5:G10,I5:I10,K5:K10,M5:M10,O5:O10,Q5:Q10,S5:S10,U5:U10,W5:W10,Y5:Y10,AA5:AA10,AC5:AC10,AE5:AE10,AG5:AG10,AI5:AI10,AM5:AM10,E29:E34,G29:G34,I29:I34,K29:K34,M29:M34,O29:O34,Q29:Q34,S29:S34,U29:U34,W29:W34,E65:E69,G65:G69,I65:I69,K65:K69,M65:M69,O65:O69,Q65:Q69,S65:S69,U65:U69,W65:W69,Y65:Y69,AA65:AA69,AC65:AC69")
        .NumberFormat = "$#,##0.00"
End with
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,378
I think there is a limit of 30 areas within a one Range reference, but I'm not positive. Maybe you should consider using a loop like jasonb75 suggested. Or you would have to split it up into multiple range references each with 30 or less areas.
 

Siyanna

Well-known Member
Joined
Nov 7, 2011
Messages
1,146
Thank You ALPHAFROG

I am having this weird problem when i open my spreadsheet and enable macros. I am getting this dialogue box all the time (Not enough recources to display completely)

Anyone know how to get round this problem?
 

Watch MrExcel Video

Forum statistics

Threads
1,122,514
Messages
5,596,609
Members
414,080
Latest member
penguin23

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
Top