Add grand subtotal

jeffreybrown

Well-known Member
Joined
Jul 28, 2004
Messages
5,152
Hi All,

A friend help put this macro together which works great, but the one piece we are stuck on is how to add a grand subtotal at the bottom. The subtotal's right now are all dynamic, that is, there is no pattern to the row they could display on. Of course the data presented is just a very small snipet of the larger data set which is about 5000 rows. The macro is dividing the data at each change in column I - OSC which could be upwords of 400. Thank you for the help.

Before Macro
Before

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 43px"><COL style="WIDTH: 47px"><COL style="WIDTH: 81px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>I</TD><TD>T</TD><TD>AR</TD><TD>AS</TD><TD>AT</TD><TD>AU</TD><TD>AV</TD><TD>AW</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">OSC</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">RIC</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">Current</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2009</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2010</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2011</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2012</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2013</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0004</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>FMN</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>FMN</TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>FMP</TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>FMP</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4

After Macro
Before


<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 43px"><COL style="WIDTH: 47px"><COL style="WIDTH: 81px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>I</TD><TD>T</TD><TD>AR</TD><TD>AS</TD><TD>AT</TD><TD>AU</TD><TD>AV</TD><TD>AW</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">OSC</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">RIC</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">Current</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2009</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2010</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2011</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2012</TD><TD style="FONT-WEIGHT: bold; COLOR: #0000ff; TEXT-ALIGN: center">FY2013</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>FMFC</TD><TD style="TEXT-ALIGN: center">0004</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0004</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD></TD><TD></TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">SUBTOTAL</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">5</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">4</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">9</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">4</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">4</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">13</TD><TD>FMN</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">14</TD><TD>FMN</TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">15</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">16</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0004</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">17</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">18</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">19</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">20</TD><TD></TD><TD></TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">SUBTOTAL</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">6</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">6</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">21</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">22</TD><TD>FMP</TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">23</TD><TD>FMP</TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">24</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">25</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0004</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">26</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0104</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">27</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0160</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: center">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">28</TD><TD></TD><TD></TD><TD style="TEXT-ALIGN: center">0161</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD><TD style="TEXT-ALIGN: center">0</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">29</TD><TD></TD><TD></TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">SUBTOTAL</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD><TD style="BACKGROUND-COLOR: #c0c0c0; TEXT-ALIGN: center">2</TD></TR></TBODY></TABLE>


<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>AS7</TD><TD>=SUMIF($T$2:$T$5,$AR$7,AS$2:AS$5)</TD></TR><TR><TD>AS11</TD><TD>=SUM(AS7:AS10)</TD></TR><TR><TD>AS16</TD><TD>=SUMIF($T$13:$T$14,$AR$16,AS$13:AS$14)</TD></TR><TR><TD>AS20</TD><TD>=SUM(AS16:AS19)</TD></TR><TR><TD>AS25</TD><TD>=SUMIF($T$22:$T$23,$AR$25,AS$22:AS$23)</TD></TR><TR><TD>AS29</TD><TD>=SUM(AS25:AS28)</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>


Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
Code:
Sub insrows()
Application.ScreenUpdating = False
Application.EnableEvents = False
Application.Calculation = xlCalculationManual
Dim rng As Range
Dim listrng As Range
lastrow = Worksheets("Before").Range("I65536").End(xlUp).Row
Set rng = Sheets("Before").Range("I2:I" & lastrow)
ListRow = Worksheets("list").Range("B65536").End(xlUp).Row
Set listrng = Sheets("list").Range("B2:B" & ListRow)
Call getlist.pvilist
arrsize = ListRow - 1
Dim sumtot()
ReDim sumtot(1 To arrsize)
For Each c In listrng
Search = c.Value
a = 0
For i = lastrow To 1 Step -1
    If Cells(i, "I").Value = Search Then
 
        cnt = "I" & 2 & ":I" & lastrow
        Set cntrng = Range(cnt)
        countvals = WorksheetFunction.CountIf(cntrng, Search)
 
        a = a + 1
        Range("I" & i + 1 & ":I" & i + 7).EntireRow.Insert
        Cells(i + 2, "AR").Value = "'0004"
        Cells(i + 3, "AR").Value = "'0104"
        Cells(i + 4, "AR").Value = "'0160"
        Cells(i + 5, "AR").Value = "'0161"
 
        Application.CutCopyMode = False
        Cells(i + 6, "AR").Value = "SUBTOTAL"
        Range("AR" & i + 6 & ":AW" & i + 6).Interior.ColorIndex = 15
        sumrng1 = "AS" & i + 2 & ":AS" & i + 5
        sumrng2 = "AS$" & i - countvals + 1 & ":AS$" & i
        crit1 = "$T$" & i - countvals + 1 & ":$T$" & i
        crit2 = "$AR$" & i + 2
        crit3 = "$AR$" & i + 3
        crit4 = "$AR$" & i + 4
        crit5 = "$AR$" & i + 5
 
        'insert sumifs
        Cells(i + 2, "AS").Value = "=Sumif(" & crit1 & "," & crit2 & "," & sumrng2 & ")"
        Cells(i + 3, "AS").Value = "=Sumif(" & crit1 & "," & crit3 & "," & sumrng2 & ")"
        Cells(i + 4, "AS").Value = "=Sumif(" & crit1 & "," & crit4 & "," & sumrng2 & ")"
        Cells(i + 5, "AS").Value = "=Sumif(" & crit1 & "," & crit5 & "," & sumrng2 & ")"
        Range("AS" & i + 2 & ":AS" & i + 5).Copy Destination:=Range("AS" & i + 2 & ":AS" & i + 5).Offset(0, 1)
        Range("AS" & i + 2 & ":AS" & i + 5).Copy Destination:=Range("AS" & i + 2 & ":AS" & i + 5).Offset(0, 2)
        Range("AS" & i + 2 & ":AS" & i + 5).Copy Destination:=Range("AS" & i + 2 & ":AS" & i + 5).Offset(0, 3)
        Range("AS" & i + 2 & ":AS" & i + 5).Copy Destination:=Range("AS" & i + 2 & ":AS" & i + 5).Offset(0, 4)
 
        'insert sumtotal
        Cells(i + 6, "AS").Value = "=Sum(" & sumrng1 & ")"
        Cells(i + 6, "AS").Copy Destination:=Cells(i + 6, "AS").Offset(0, 1)
        Cells(i + 6, "AS").Copy Destination:=Cells(i + 6, "AS").Offset(0, 2)
        Cells(i + 6, "AS").Copy Destination:=Cells(i + 6, "AS").Offset(0, 3)
        Cells(i + 6, "AS").Copy Destination:=Cells(i + 6, "AS").Offset(0, 4)
        Range("A1").Select
 
        Cells(i + 6, "AS").Select
        i = 0
 
        Exit For
 
    End If
Next i
Next c
Application.ScreenUpdating = True
Application.EnableEvents = True
Application.Calculate
Application.Calculation = xlCalculationAutomatic
End Sub
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Jeff, I won't critique the code or review in full but in principle what you want to do is use something like:

Code:
Cells(Rows.Count,"AS").End(xlUp).Offset(2).Resize(,5).FormulaR1C1 = "=SUMIF(R1C44:R[-1]C44,""SUBTOTAL"",R1C:R[-1]C)"
 
Upvote 0
Thanks Luke. I would guess using this same syntax I could consolidate the other formulas? I'll give it a shot.
 
Upvote 0
Yes, I would suspect you could condense your code quite significantly but if it works don't mess too much ;)
 
Upvote 0
Luke,

As I'm sure you know after seeing the code it works off of a unique list. The original code was built using a pivot table, but I was thinking this piece of code would be simpler and cleaner. I tried changing the Set Rng to
Code:
Set Rng = Range(Sheets("Before").Range("I1"), Sheets("Before").Range("I" & Rows.Count).End(xlUp))
But I get an error 400. Any thoughts?
Code:
Sub FilterUnique()
Dim Rng As Range, Dn As Range
Set Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
With CreateObject("scripting.dictionary")
.comparemode = vbTextCompare
For Each Dn In Rng
If Not .Exists(Dn.Value) Then
.Add Dn.Value, ""
End If
Next
Sheets("Sheet2").Range("A1").Resize(.Count).Value = Application.Transpose(.keys)
End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,647
Messages
6,120,722
Members
448,987
Latest member
marion_davis

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