+ Reply to Thread
Results 1 to 5 of 5

Case sensitive counting of character instances in text strings.

  1. #1
    Registered User
    Join Date
    02-15-2012
    Location
    NC
    MS-Off Ver
    Excel 2010
    Posts
    4

    Case sensitive counting of character instances in text strings.

    I am currently using this formula =IF(COUNTIF($H26:$AI26,AM$2)>0,COUNTIF($H26:$AI26,AM$2),"")
    to look at a range of text and count all instances of matching characters in my header row.

    I have to manually count Capital letters currently and manually deduct them from the lowercase count.

    I can visualize using LEN to count the characters and looping Find which is case sensitive x times per word
    but when I try this i get ####.

    Header row character strings - 0,1,2,3(etc),a,b,c(etc),A,B,C(etc)
    ---------------------------------------------------------------
    122 Meeting Room Fifth floor - 0,1,2,0(etc),0,0,0,(etc),0,0,0(etc)
    202 Consultation Room - 1,0,2,0(etc),1,0,0,(etc),0,0,1(etc)
    ---------------------------------------------------------------
    Totals - 1,1,4,0(etc),1,0,0,(etc),0,0,1(etc)

    A little background - we laser cut letters with mounting holes. Every character has a unique mounting pattern so when we process a job we count up all instances of the same letter and process them all at the same time. An uppercase and lowercase letter have different mounts so we need to count them separately. My manual method has worked for a long time but orders with 1000+ letters get a bit confusing.

    Any help is appreciated.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Help - Case sensitive counting of character instances in text strings.

    Try:

    =SUMPRODUCT(--(EXACT($H26:$AI26,AM$2))
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    02-15-2012
    Location
    NC
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: Case sensitive counting of character instances in text strings.

    Thank you for the reply - your solution did not work, however it did prompt me to look at Substitute and I came up with this workaround. The code is pretty chunky and any recommendations on tightening it up is appreciated.

    =IF(SUM(LEN(SUBSTITUTE($A8," ",))-LEN(SUBSTITUTE(SUBSTITUTE($A8," ",),I$2,)))>0,SUM(LEN(SUBSTITUTE($A8," ",))-LEN(SUBSTITUTE(SUBSTITUTE($A8," ",),I$2,)))

    $A8 - is the text string to evaluate.
    I$2 - is one value in a row of upper and lowercase numbers running across the chart.

    The first step is to use substitute to locate all spaces and strip them out by replacing them with nothing. (Test Room - becomes TestRoom)
    I then count the remaining characters which gives me the total count for the text string. (TestRoom = 8 characters)
    The next step is to substitute any corresponding letters in I$2 with nothing and then recount. (If evaluating e = TstRoom = 7 characters)
    Last I compare the original count (8) with the new count (7) and find there was 1 instance of the evaluated character in the text string.

    This works because substitute is case sensitive and will differentiate between the T and t in Test Room.

    The Exact would not hit on anything because I was looking for t in Test Room and it requires all parts of the two strings to match - from what I observed.

    Thanks again for the response, and any recommendations on shortening the code is appreciated.

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    Microsoft 365
    Posts
    14,699

    Re: Case sensitive counting of character instances in text strings.

    I assume that NBVC inferred that you had one letter in each cell, in which case using EXACT would be the preferable approach. For the situation where A8 contains a text string and A2 a single letter can you just use

    =LEN($A8)-LEN(SUBSTITUTE($A8,I$2,""))

    I don't see why you need to remove spaces
    Audere est facere

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Case sensitive counting of character instances in text strings.

    Yes, that is what I had assumed

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1