Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 34
Default Macro to insert formulas in the last row of different worksheets

Hello,

I need a macro that will insert two formulas below the last row of column AB
in every worksheet I have in a workbook. The number of rows in each
worksheet varies so I never know what the last row is. In addition, I need
to include headers to the left of each cell that contains the formula.

The two formulas that I need to insert average data based on conditions in
two other columns. The two formulas a

Average Increase {=AVERAGE(IF(([RANGE IN COLUMN N]0)*([RANGE IN COLUMN
P]<110), [RANGE IN COLUMN AB]))}

Casual Average Increase {=AVERAGE(IF(([RANGE IN COLUMN N]=0)*([RANGE IN
COLUMN P]<110), [RANGE IN COLUMN AB]))}

Thanks in advance.

-Scott

  #2   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 49
Default Macro to insert formulas in the last row of different worksheets

Scott,

Try this for size:

It makes the following assumptions:
Every worksheet has the same kind of structure.
The data is in a nice block; in other words, no information in N and P lies
below the last entry in AB.
The information block begins in Row 1 (Header or not).
There are at least TWO clear rows at the bottom of column AB.

Sub Main()
'Purpose: to run InsertAVGFormulas procedure on every worksheet.
Dim wks As Worksheet
For Each wks In ActiveWorkbook.Worksheets
wks.Select
Call InsertAVGFormulas
Next
End Sub

Sub InsertAVGFormulas()
'Purpose: Inserts array formulas at the bottom of Col AB.
Dim lLastRow As Long
Dim sAdrsN As String
Dim sAdrsP As String
Dim sAdrsAB As String
Dim sAvgIncrease As String
Dim sCasualAvgIncrease As String

'Find the last Row based on column AB.
lLastRow = Range("AB" & CStr(Rows.Count)).End(xlUp).Row

'Make addresses for ranges.
'FormulaArray always uses R1C1 reference style, not the A1 reference
style.
'So the addresses are in (absolute) R1C1 style.
sAdrsN = Range("N1:N" & CStr(lLastRow)).Address(True, True, xlR1C1)
sAdrsP = Range("P1:P" & CStr(lLastRow)).Address(True, True, xlR1C1)
sAdrsAB = Range("AB1:AB" & CStr(lLastRow)).Address(True, True, xlR1C1)

'Create Average formula strings.
sAvgIncrease = "=AVERAGE(IF((" & sAdrsN & "0)*(" & sAdrsP & "<110)," &
sAdrsAB & "))"
sCasualAvgIncrease = "=AVERAGE(IF((" & sAdrsN & "=0)*(" & sAdrsP &
"<110)," & sAdrsAB & "))"

'Now insert formulas; BRACKETS INSERTED BY EXCEL!
Range("AB" & CStr(lLastRow + 1)).FormulaArray = sAvgIncrease
Range("AB" & CStr(lLastRow + 2)).FormulaArray = sCasualAvgIncrease

End Sub

If MSP = Member of the Scottish Parliament, you owe me a wee dram.

Regards
Paul

"ScottMSP" wrote in message
...
Hello,

I need a macro that will insert two formulas below the last row of column
AB
in every worksheet I have in a workbook. The number of rows in each
worksheet varies so I never know what the last row is. In addition, I
need
to include headers to the left of each cell that contains the formula.

The two formulas that I need to insert average data based on conditions in
two other columns. The two formulas a

Average Increase {=AVERAGE(IF(([RANGE IN COLUMN N]0)*([RANGE IN COLUMN
P]<110), [RANGE IN COLUMN AB]))}

Casual Average Increase {=AVERAGE(IF(([RANGE IN COLUMN N]=0)*([RANGE IN
COLUMN P]<110), [RANGE IN COLUMN AB]))}

Thanks in advance.

-Scott



Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Macro that will Insert Formulas in last row of different worksheet ScottMSP Excel Programming 0 February 11th 09 07:28 PM
Macro help. Insert row and copy formulas from row above Kesbutler Excel Programming 3 February 5th 09 04:12 PM
How to insert formulas from four worksheets into one worksheet Corinne Excel Worksheet Functions 1 November 1st 07 07:06 PM
Macro to insert copy and insert formulas only to next blank row bob Excel Programming 0 June 30th 06 12:02 PM
insert scanned worksheets,then apply formulas, similiar to backgr. hinterland_1 Excel Programming 0 January 26th 05 06:07 AM


All times are GMT +1. The time now is 05:28 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"