Counting the (1) in a binary code string !

serge

Well-known Member
Joined
Oct 8, 2008
Messages
1,410
Office Version
  1. 2007
Platform
  1. Windows
Hi,

I'm working with binary code on the left side from P:AN, and on the right, I'm looking for a formula that will be able to count the (1) as long as they are not separated by a (0).So for example the first row P9:AN9.The formula will start in cell AQ9 and drag to the right, is that possible ? Thank you.
Excel Workbook
PQRSTUVWXYZAAABACADAEAFAGAHAIAJAKALAMANAOAPAQARASATAUAVAW
91001000001010010100011111111
10101010011011100011110101112341
11110100001000011101100011211322
1211110111001110111101110043343
1311000011000101101100022122
1410000001001110100001010111131112
151111111011101010011011731122
Sheet
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Somebody asked a similar question just 2 or 3 days ago but for one column.
That was resolved and should be easily applied to rows.
I think the person was asking to COUNT consecutive 1's.
That may be enough for both of us to do a search of recent days or maybe wait for the "solver" to appear.


(Hope for the "solver" unless you are successful, I tried a few options but sadly missed.)
 
Last edited:
Upvote 0
Does any one has a idea please ?
Serge.
 
Upvote 0
I know you asked for a formula, but I could not think of one, so I developed a macro for you to consider instead...
Code:
[table="width: 500"]
[tr]
	[td]Sub CountConsecutiveOnes()
  Dim R As Long, X As Long, Ones As Variant, Data As Variant, Result As Variant
  Data = Range("AN9").CurrentRegion.Value
  ReDim Result(1 To UBound(Data, 1), 1 To UBound(Data, 2))
  For R = 1 To UBound(Data)
    Ones = Split(Application.Trim(Replace(Join(Application.Index(Data, R), ""), 0, " ")))
    For X = 0 To UBound(Ones)
      Result(R, X + 1) = Len(Ones(X))
    Next
  Next
  Range("AQ9").Resize(UBound(Result, 1), UBound(Result, 2)) = Result
End Sub[/td]
[/tr]
[/table]

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (CountConsecutiveOnes) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "Yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
Maybe this array formula

AQ9 copied across and down
=IFERROR(INDEX(FREQUENCY(IF($P9:$AN9=1,COLUMN($P9:$AN9)),IF(($P9:$AN9=0)*($Q9:$AO9=1),COLUMN($P9:$AN9))),COLUMNS($AQ9:AQ9)+1),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
Small adjustment...

New version
Array formula in AQ9 copied across and down
=IFERROR(INDEX(FREQUENCY(IF($P9:$AN9=1,COLUMN($P9:$AN9)),IF(($P9:$AN9=0)*($Q9:$AO9=1),COLUMN($P9:$AN9))),COLUMNS($AQ9:AQ9)+IF($P9=1,0,1)),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
If you can lilive with the trailing N/As,

P​
Q​
R​
S​
T​
U​
V​
W​
X​
Y​
Z​
AA​
AB​
AC​
AD​
AE​
AF​
AG​
AH​
AI​
AJ​
AK​
AL​
AM​
AN​
AO​
AP​
AQ​
AR​
AS​
AT​
AU​
AV​
AW​
AX​
9​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
10​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
2​
3​
4​
1​
11​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
2​
1​
1​
3​
2​
2​
#N/A​
12​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
1​
4​
3​
3​
4​
3​
#N/A​
#N/A​

Array-entered in AQ9:AX9,

=IFERROR(1 / (1/TRANSPOSE(FREQUENCY(IF(P9:AN9=1, COLUMN(P9:AN9)), IF((P9:AN9 = 1) * (Q9:AO9 <> 1), COLUMN(P9:AN9))))), "")
 
Upvote 0
Wow, Thank you to every one of you, I really appreciate this precious help.
Serge.
 
Upvote 0

Forum statistics

Threads
1,215,483
Messages
6,125,064
Members
449,206
Latest member
Healthydogs

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