Matrix formula to count months

Maurizio

Well-known Member
Joined
Oct 15, 2002
Messages
687
Office Version
  1. 2007
Platform
  1. Windows
Hi all,

with this DB

Targa Data 1 Data 2 Data 3 Data 4 Data 5
DT101E1 31/05/19
DT101E2 08/02/19 07/05/19 31/05/19
DT101E3 06/03/19
DT101E4 23/02/19
DT101E5 19/04/19 10/05/19 31/05/19
DT101E6 14/06/19
DT101E7 12/12/19


I need a formula for sum months


Month 1 2 3 4 5 6 7 8 9 10 11 12
DT101E1 1
DT101E2 1 2
DT101E3 1
DT101E4 1
DT101E5 1 2
DT101E6 1
DT101E7 1



Tia.
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
something like this?

Count of MonthMonth
Targa
2
3
4
5
6
12
DT101E1
1​
DT101E2
1​
2​
DT101E3
1​
DT101E4
1​
DT101E5
1​
2​
DT101E6
1​
DT101E7
1​
 
Upvote 0
so

SOURCEAlt+D+PPowerQuery
TargaData1Data2Data3Data4Data5Count of ColumnValueTarga2345612
DT101E1
31/05/2019​
RowFebMarAprMayJunDecDT101E1
1​
DT101E2
08/02/2019​
07/05/2019​
31/05/2019​
DT101E1
1​
DT101E2
1​
2​
DT101E3
06/03/2019​
DT101E2
1​
2​
DT101E3
1​
DT101E4
23/02/2019​
DT101E3
1​
DT101E4
1​
DT101E5
19/04/2019​
10/05/2019​
31/05/2019​
DT101E4
1​
DT101E5
1​
2​
DT101E6
14/06/2019​
DT101E5
1​
2​
DT101E6
1​
DT101E7
12/12/2019​
DT101E6
1​
DT101E7
1​
DT101E7
1​

in PivotTable filter null (blank)

M-code for PowerQuery
Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"Targa", type text}, {"Data1", type datetime}, {"Data2", type datetime}, {"Data3", type datetime}, {"Data4", type any}, {"Data5", type any}}),
    UOC = Table.UnpivotOtherColumns(Type, {"Targa"}, "Attribute", "Value"),
    Month = Table.TransformColumns(UOC,{{"Value", Date.Month, Int64.Type}}),
    Rename = Table.RenameColumns(Month,{{"Value", "Month"}}),
    Pivot = Table.Pivot(Table.TransformColumnTypes(Rename, {{"Month", type text}}, "en-GB"), List.Distinct(Table.TransformColumnTypes(Rename, {{"Month", type text}}, "en-GB")[Month]), "Month", "Attribute", List.Count),
    Replace = Table.ReplaceValue(Pivot,0,null,Replacer.ReplaceValue,{"2", "3", "4", "5", "6", "12"}),
    ROC = Table.SelectColumns(Replace,{"Targa", "2", "3", "4", "5", "6", "12"})
in
    ROC[/SIZE]
 
Last edited:
Upvote 0
A
B
C
D
E
F
G
H
I
J
K
L
M
N
O
P
Q
1
TargaData1Data2Data3Data4Data5Data6Data7Data8Data9Data10Data11Data12Data13Data14Data15Data16
2
DT101E1
5/31/2019​
3
DT101E2
2/8/2019​
5/7/2019​
5/31/2019​
4
DT101E3
3/6/2019​
5
DT101E4
2/23/2019​
6
DT101E5
4/19/2019​
5/10/2019​
5/31/2019​
7
DT101E6
6/14/2019​
8
DT101E7
12/12/2019​
9
10
11
12
Targa
JAN
FEB
MAR
APR
MAY
JUN
JUL
AUG
SEP
OCT
NOV
DEC
13
DT101E1
0​
0​
0​
0​
1​
0​
0​
0​
0​
0​
0​
0​
14
DT101E2
0​
1​
0​
0​
2​
0​
0​
0​
0​
0​
0​
0​
15
DT101E3
0​
0​
1​
0​
0​
0​
0​
0​
0​
0​
0​
0​
16
DT101E4
0​
1​
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
17
DT101E5
0​
0​
0​
1​
2​
0​
0​
0​
0​
0​
0​
0​
18
DT101E6
0​
0​
0​
0​
0​
1​
0​
0​
0​
0​
0​
0​
19
DT101E7
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
1​

<tbody>
</tbody>

B13=
IF(AND($A13<>"",B$12<>""),SUMPRODUCT(($A$2:$A$8=$A13)*(MONTH($B$2:$Q$8)=MONTH(B$12&0))*($B$2:$Q$8<>"")),"")

Copy across and down


Saluti da Milano

 
Last edited:
Upvote 0
A
B
C
D
E
F
G
H
I
J
K
L
M
N
O
P
Q
1
TargaData1Data2Data3Data4Data5Data6Data7Data8Data9Data10Data11Data12Data13Data14Data15Data16
2
DT101E1
5/31/2019​
3
DT101E2
2/8/2019​
5/7/2019​
5/31/2019​
4
DT101E3
3/6/2019​
5
DT101E4
2/23/2019​
6
DT101E5
4/19/2019​
5/10/2019​
5/31/2019​
7
DT101E6
6/14/2019​
8
DT101E7
12/12/2019​
9
10
11
12
Targa
JAN
FEB
MAR
APR
MAY
JUN
JUL
AUG
SEP
OCT
NOV
DEC
13
DT101E1
0​
0​
0​
0​
1​
0​
0​
0​
0​
0​
0​
0​
14
DT101E2
0​
1​
0​
0​
2​
0​
0​
0​
0​
0​
0​
0​
15
DT101E3
0​
0​
1​
0​
0​
0​
0​
0​
0​
0​
0​
0​
16
DT101E4
0​
1​
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
17
DT101E5
0​
0​
0​
1​
2​
0​
0​
0​
0​
0​
0​
0​
18
DT101E6
0​
0​
0​
0​
0​
1​
0​
0​
0​
0​
0​
0​
19
DT101E7
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
0​
1​

<tbody>
</tbody>

B13=
IF(AND($A13<>"",B$12<>""),SUMPRODUCT(($A$2:$A$8=$A13)*(MONTH($B$2:$Q$8)=MONTH(B$12&0))*($B$2:$Q$8<>"")),"")

Copy across and down


Saluti da Milano


Interessante Marzio, la adatterò alla versione ita.
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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