Help with a macro,

jocote46

New Member
Joined
May 11, 2009
Messages
44
Hello,

1.I have the following code that i created but i'm getting an error on the WS.range line , i''m copying the date from column C to D and then i want the Column D date to be formatted to "YYYY" but I'm getting a "Run time error" .
2. I want to use the following array formula on Cell "P2" and copy all the way down to lastrow , using column "C" as reference. but when i tried to use the formula it didn't work.


VBA Code:
Sub APsummaries()

Dim WS As Worksheet
Set WS = ActiveSheet

ActiveSheet.Select
Range("C:C").Copy
Range("D:D").Insert
Range("D1").Value = "Year"
WS.Range("D:D") = Application.WorksheetFunction.Text(WS.Range("D:D"), "yyyy")
Columns("H").NumberFormat = "General"
Range("N1").Value = "Top 10"
Range("O1").Value = "Aging per Inv"
Range("P1").Value = "Aging Bucket per Inv"
Range("Q1").Value = "BU"
Range("O2").Formula = "=DAYS(TODAY(), C2)"
Range("P2"),Formula = "=IF(O2>90,"91 and Over",IF(O2>60,"61-90 days",IF(O2>30,"31-60 days",IF(O2<0,"Future Due","Current Period"))))"
Range("Q2").Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub

Thank you in advance for your expertise and assistance. let me know if you have any questions.
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.

JB2020

Board Regular
Joined
Jul 29, 2020
Messages
80
Office Version
  1. 365
  2. 2016
  3. 2010
Platform
  1. Windows
Hello,

1.I have the following code that i created but i'm getting an error on the WS.range line , i''m copying the date from column C to D and then i want the Column D date to be formatted to "YYYY" but I'm getting a "Run time error" .
2. I want to use the following array formula on Cell "P2" and copy all the way down to lastrow , using column "C" as reference. but when i tried to use the formula it didn't work.


VBA Code:
Sub APsummaries()

Dim WS As Worksheet
Set WS = ActiveSheet

ActiveSheet.Select
Range("C:C").Copy
Range("D:D").Insert
Range("D1").Value = "Year"
WS.Range("D:D") = Application.WorksheetFunction.Text(WS.Range("D:D"), "yyyy")
Columns("H").NumberFormat = "General"
Range("N1").Value = "Top 10"
Range("O1").Value = "Aging per Inv"
Range("P1").Value = "Aging Bucket per Inv"
Range("Q1").Value = "BU"
Range("O2").Formula = "=DAYS(TODAY(), C2)"
Range("P2"),Formula = "=IF(O2>90,"91 and Over",IF(O2>60,"61-90 days",IF(O2>30,"31-60 days",IF(O2<0,"Future Due","Current Period"))))"
Range("Q2").Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub

Thank you in advance for your expertise and assistance. let me know if you have any questions.

The main problem is that the text function will only take a single value, so passing a column into it will cause an error. I would replace that line with something like this:

VBA Code:
WS.Range("D:D").FormulaR1C1 = "=IF(RC[-1]="""","""",TEXT(RC[-1],"""yyyy"""))"
WS.Range("D:D").value = WS.Range("D:D").value

So basically just put the formula into the column and then paste the values over it. I also went on the assumption that It should be C:C, rather than D:D in Application.WorksheetFunction.Text(WS.Range("D:D"), "yyyy")?

VBA Code:
Sub APsummaries()

Dim WS As Worksheet
Set WS = ActiveSheet

ActiveSheet.Select
Range("D:D").Insert
WS.Range("D:D").FormulaR1C1 = "=IF(RC[-1]="""","""",TEXT(RC[-1],"""yyyy"""))"
WS.Range("D:D").value = WS.Range("D:D").value
Range("D1").Value = "Year"
Columns("H").NumberFormat = "General"
Range("N1").Value = "Top 10"
Range("O1").Value = "Aging per Inv"
Range("P1").Value = "Aging Bucket per Inv"
Range("Q1").Value = "BU"
Range("O2").Formula = "=DAYS(TODAY(), C2)"
Range("P2"),Formula = "=IF(O2>90,"91 and Over",IF(O2>60,"61-90 days",IF(O2>30,"31-60 days",IF(O2<0,"Future Due","Current Period"))))"
Range("Q2").Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
73,402
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Sub APsummaries()
   Dim UsdRws As Long
   
   UsdRws = Range("C" & Rows.Count).End(xlUp).Row
   Range("D1").Value = "Year"
   With Range("D2:D" & UsdRws)
      .Formula = "=text(c2,""yyyy"")"
      .Value = .Value
   End With
   Columns("H").NumberFormat = "General"
   Range("N1").Value = "Top 10"
   Range("O1").Value = "Aging per Inv"
   Range("P1").Value = "Aging Bucket per Inv"
   Range("Q1").Value = "BU"
   Range("O2:O" & UsdRws).Formula = "=DAYS(TODAY(), C2)"
   Range("P2:P" & UsdRws).Formula = "=IF(O2>90,""91 and Over"",IF(O2>60,""61-90 days"",IF(O2>30,""31-60 days"",IF(O2<0,""Future Due"",""Current Period""))))"
   Range("Q2:Q" & UsdRws).Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub
 

jocote46

New Member
Joined
May 11, 2009
Messages
44
How about
VBA Code:
Sub APsummaries()
   Dim UsdRws As Long
  
   UsdRws = Range("C" & Rows.Count).End(xlUp).Row
   Range("D1").Value = "Year"
   With Range("D2:D" & UsdRws)
      .Formula = "=text(c2,""yyyy"")"
      .Value = .Value
   End With
   Columns("H").NumberFormat = "General"
   Range("N1").Value = "Top 10"
   Range("O1").Value = "Aging per Inv"
   Range("P1").Value = "Aging Bucket per Inv"
   Range("Q1").Value = "BU"
   Range("O2:O" & UsdRws).Formula = "=DAYS(TODAY(), C2)"
   Range("P2:P" & UsdRws).Formula = "=IF(O2>90,""91 and Over"",IF(O2>60,""61-90 days"",IF(O2>30,""31-60 days"",IF(O2<0,""Future Due"",""Current Period""))))"
   Range("Q2:Q" & UsdRws).Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub
HI Fluff,

Thanks for your help, i wanted to insert a new column "D" , i don't want to replace the data that i already have in Column D. i added the copy and insert code, however the formula is to convert the data on Column D to "YYYY" basically what i want is to use the year on Column C and show just the year on column D. As you can see in the picture , the current formula didn't do the job as expected.

once we figure this "YYYY" it should work as planned.

VBA Code:
Sub APsummaries()
   Dim UsdRws As Long
   
   Range("C:C").Copy
   Range("D:D").Insert
   UsdRws = Range("C" & Rows.Count).End(xlUp).Row
   Range("D1").Value = "Year"
   With Range("D2:D" & UsdRws)
      .Formula = "=text(c2,""yyyy"")"
      .Value = .Value
   End With
   Columns("H").NumberFormat = "General"
   Range("N1").Value = "Top 10"
   Range("O1").Value = "Aging per Inv"
   Range("P1").Value = "Aging Bucket per Inv"
   Range("Q1").Value = "BU"
   Range("O2:O" & UsdRws).Formula = "=DAYS(TODAY(), C2)"
   Range("P2:P" & UsdRws).Formula = "=IF(O2>90,""91 and Over"",IF(O2>60,""61-90 days"",IF(O2>30,""31-60 days"",IF(O2<0,""Future Due"",""Current Period""))))"
   Range("Q2:Q" & UsdRws).Formula = "=VLOOKUP(H2,'[AP Aging _Master.xlsx]AP Aging Updated'!$G$2:$AB$800,22,0)"


End Sub


Thanks again
 

Attachments

  • 1605903040895.png
    1605903040895.png
    10.9 KB · Views: 2

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
73,402
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Just delete this line
VBA Code:
Range("C:C").Copy
 

jocote46

New Member
Joined
May 11, 2009
Messages
44
The main problem is that the text function will only take a single value, so passing a column into it will cause an error. I would replace that line with something like this:

VBA Code:
WS.Range("D:D").FormulaR1C1 = "=IF(RC[-1]="""","""",TEXT(RC[-1],"""yyyy"""))"
WS.Range("D:D").value = WS.Range("D:D").value

So basically just put the formula into the column and then paste the values over it. I also went on the assumption that It should be C:C, rather than D:D in Application.WorksheetFunction.Text(WS.Range("D:D"), "yyyy")?

VBA Code:
Sub APsummaries()

Dim WS As Worksheet
Set WS = ActiveSheet

ActiveSheet.Select
Range("D:D").Insert
WS.Range("D:D").FormulaR1C1 = "=IF(RC[-1]="""","""",TEXT(RC[-1],"""yyyy"""))"
WS.Range("D:D").value = WS.Range("D:D").value
Range("D1").Value = "Year"
Columns("H").NumberFormat = "General"
Range("N1").Value = "Top 10"
Range("O1").Value = "Aging per Inv"
Range("P1").Value = "Aging Bucket per Inv"
Range("Q1").Value = "BU"
Range("O2").Formula = "=DAYS(TODAY(), C2)"
Range("P2"),Formula = "=IF(O2>90,"91 and Over",IF(O2>60,"61-90 days",IF(O2>30,"31-60 days",IF(O2<0,"Future Due","Current Period"))))"
Range("Q2").Formula = "=VLOOKUP(X2,'[Adaptive Level Hierarchy by Geoff 8.21.20_WA.xlsx]Sheet2'!$A$2:$B$300,2,0)"

End Sub
JB2020,

Thank you for your help but i'm still getting an error on the text formula. getting a compile error.
 

JB2020

Board Regular
Joined
Jul 29, 2020
Messages
80
Office Version
  1. 365
  2. 2016
  3. 2010
Platform
  1. Windows

ADVERTISEMENT

JB2020,

Thank you for your help but i'm still getting an error on the text formula. getting a compile error.
Sorry, I went a bit overboard with the quotation marks

"=IF(RC[-1]="""","""",TEXT(RC[-1],""yyyy""))"
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
73,402
Office Version
  1. 365
Platform
  1. Windows
That's Xl trying to be "helpful" by changing the format to date, add this line as shown
Rich (BB code):
   With Range("D2:D" & UsdRws)
      .Formula = "=text(c2,""yyyy"")"
      .Value = .Value
      .NumberFormat = "General"
   End With
 
Solution

jocote46

New Member
Joined
May 11, 2009
Messages
44
That's Xl trying to be "helpful" by changing the format to date, add this line as shown
Rich (BB code):
   With Range("D2:D" & UsdRws)
      .Formula = "=text(c2,""yyyy"")"
      .Value = .Value
      .NumberFormat = "General"
   End With

it worked! Yes!! Woot! thank you so much, really appreciate it.
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,488
Messages
5,837,623
Members
430,506
Latest member
TonyIbbs

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