Summarising data

EvansB2

Board Regular
Joined
Nov 25, 2008
Messages
245
Office Version
  1. 365
Platform
  1. Windows
Hi there,

I have copied samples in the form of two data tables and in essence, I would like Table 2, columns F to H, to return data from Table 1, only when the value in column C is greater than zero. Typically, Table 1 will run to thousands of rows and so it would be good to only summarise relevant data.

Any help would be much appreciated.

Ben

ABCDEFGH
1ProjectItemYear 11ProjectItemYear
2A1.1£5002A1.1£500
3B1.1£03C1.2£200
4C1.2£2004B1.3£400
5B1.3£4005C1.1£100
6B1.1£06A1.4£700
7C1.1£1007
8A1.4£700
9A1.2£0
TABLE 1TABLE 2
<colgroup><col width="29" style="width: 22pt; mso-width-source: userset; mso-width-alt: 1060;"> <col width="73" style="width: 55pt; mso-width-source: userset; mso-width-alt: 2669;" span="2"> <col width="75" style="width: 56pt; mso-width-source: userset; mso-width-alt: 2742;"> <col width="64" style="width: 48pt;"> <col width="31" style="width: 23pt; mso-width-source: userset; mso-width-alt: 1133;"> <col width="64" style="width: 48pt;" span="3"> <tbody> </tbody>
 
Ctrl+T changimg range to Excel Table that's all
PowerQuery changing source range to Excel table then load source into PQ editor where you can transform data as you wish, eg. filter column Year by 0, then load result back to the sheet

sourceresult PQ
ProjectItemYear 1ProjectItemYear 1
A
1.1​
500​
A
1.1​
500​
B
1.1​
0​
C
1.2​
200​
C
1.2​
200​
B
1.3​
400​
B
1.3​
400​
C
1.1​
100​
B
1.1​
0​
A
1.4​
700​
C
1.1​
100​
A
1.4​
700​
A
1.2​
0​
Code:
[SIZE=1]
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project", type text}, {"Item", type number}, {"Year 1", Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Year 1] <> 0))
in
    #"Filtered Rows"[/SIZE]
 
Last edited:
Upvote 0

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Hi,

I wasn't sure if you had got what you needed, but I'll post my effort in case it helps.

1) Paste the function below into a module. Thank you Chip Pearson.
2) Create two columns before you data.
3) In column 1 enter =IF(E7=0,"",C7&D7&E7). This will create a list of all the values concatenated together.
4) In column 2 highlight the range as long as your data and enter =noblanks(A7:A14). Then press SHIFT + CTRL + ENTER, this will create a list without blanks.
5) In column G (on the same line as the first line of data), enter =IF($B7="","",VLOOKUP($B7,$A$7:$E$14,3,FALSE)) and copy down as long as your range. You can then use the same formula for the columns 2 & 3.

A very messy approach but it works.

Function NoBlanks(RR As Range) As Variant
Dim Arr() As Variant
Dim R As Range
Dim N As Long
Dim L As Long
If RR.Rows.Count > 1 And RR.Columns.Count > 1 Then
NoBlanks = CVErr(xlErrRef)
Exit Function
End If

If Application.Caller.Cells.Count > RR.Cells.Count Then
N = Application.Caller.Cells.Count
Else
N = RR.Cells.Count
End If

ReDim Arr(1 To N)
N = 0
For Each R In RR.Cells
If Len(R.Value) > 0 Then
N = N + 1
Arr(N) = R.Value
End If
Next R
For L = N + 1 To UBound(Arr)
Arr(L) = vbNullString
Next L
ReDim Preserve Arr(1 To L)
If Application.Caller.Rows.Count > 1 Then
NoBlanks = Application.Transpose(Arr)
Else
NoBlanks = Arr
End If
End Function
 
Upvote 0
I'm still contemplating this one and so thanks for the response. I will certainly give it a go.
 
Upvote 0

Forum statistics

Threads
1,214,967
Messages
6,122,503
Members
449,090
Latest member
RandomExceller01

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