INDIRECT not defined in my custom formula

TTaha

New Member
Joined
Sep 7, 2020
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi,

I am trying to create this custom formula in a template file to count bytes in a string but when running it, it highlights "INDIRECT" as not defined.

VBA:

VBA Code:
Public Function ByteCount(text As String)

ByteCount = IfError(Sum(IIf(Unicode(Mid(text, Row(INDIRECT("1:" & Len(text))), 1)) < 128, 1, IIf(Unicode(Mid(text, Row(INDIRECT("1:" & Len(text))), 1)) < 2048, 2, IIf(Unicode(Mid(text, Row(INDIRECT("1:" & Len(text))), 1)) < 65536, 3, 4)))), 0)

End Function

and here is the Excel formula working perfectly:
Excel Formula:
=IFERROR(SUM(
    IF(UNICODE(MID(A3;ROW(INDIRECT("1:"&LEN(A3)));1))<128; 1;
    IF(UNICODE(MID(A3;ROW(INDIRECT("1:"&LEN(A3)));1))<2048; 2;
    IF(UNICODE(MID(A3;ROW(INDIRECT("1:"&LEN(A3)));1))<65536; 3; 4
))));0)

Is there an easy way to let my colleages use this formula in an easy way? your help will be highly appreciated.

Cheers,
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
VBA functions are not the same as worksheet functions.

VBA Code:
Public Function ByteCount(text As String)

    Dim i As Long

    For i = 1 to Len(text)

        Select Case CHRW(Mid(text,i,1))

            Case <128

                ByteCount = ByteCount + 1

            Case <2048

                ByteCount = ByteCount + 2

            Case <65536

                ByteCount = ByteCount + 4

            Case Else

                ByteCount = ByteCount + 4

        End Select

    Next i

End Function

Also, about the worksheet formulas, the Volatile ROW(INDIRECT("1:" & LEN(A3))) can be replaced with ROW(A1:INDEX(A:A, Len(A3),1))
 
Upvote 0
VBA functions are not the same as worksheet functions.

VBA Code:
Public Function ByteCount(text As String)

    Dim i As Long

    For i = 1 to Len(text)

        Select Case CHRW(Mid(text,i,1))

            Case <128

                ByteCount = ByteCount + 1

            Case <2048

                ByteCount = ByteCount + 2

            Case <65536

                ByteCount = ByteCount + 4

            Case Else

                ByteCount = ByteCount + 4

        End Select

    Next i

End Function

Also, about the worksheet formulas, the Volatile ROW(INDIRECT("1:" & LEN(A3))) can be replaced with ROW(A1:INDEX(A:A, Len(A3),1))

Thank you for the help.

Sadly, the VBA code you provided returns #value error. I am sorry for the hassle, this is my first custom function.
 
Upvote 0
Thank you so much for the help and sorry for the late reply.

I am posting here the final version after a couple of edits which covers Asian characters too and works well for me

VBA Code:
Public Function ByteCount(text As String)

Dim i As Long

For i = 1 To Len(text)

Select Case AscW(Mid(text, i, 1))

Case Is < 0

ByteCount = ByteCount + 3

Case Is < 128

ByteCount = ByteCount + 1

Case Is < 2048

ByteCount = ByteCount + 2

Case Else

ByteCount = ByteCount + 3

End Select

Next i

End Function
 
Upvote 0

Forum statistics

Threads
1,213,513
Messages
6,114,072
Members
448,546
Latest member
KH Consulting

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