Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 1
Default Range Parameters in Function

Greetings All,

I am trying to understand why this function does not work. Any
suggestions would greatly be appreciated it.

Public Function GetArray(ByVal rng1 As Range, ByVal rng2 As Range) As
String
' rng1 is a 1-cell range; rng2 1-cell range
Dim vReturn As Variant
Dim oSecret As Object
Dim i As Integer

On Error GoTo ErrorHandler
Set oSecret = CreateObject("SomeDLL.Class")
vReturn = oSecret.GetSecretArray(rng1.Cells.Value)

GetArray = vbNullString
For i = 0 to UBound(vReturn) Step 1
GetArray = GetArray & vReturn(i) ' this is line is fine
rng2.Cells(i + 1).Value = vReturn(i) ' this line kicks the function
out; rng2.Offset(i) does not work either, rng2.<whatever.FormulaR1C1
does not help either
Next i
Exit Function
:ErrorHandler
MsgBox Err.Description
End Function

  #2   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 1,071
Default Range Parameters in Function

The only thing you can do in a user defined function (UDF) is return a
value.

That value can be an array of values. Suppose you want the returned values
in a range of contiguous cells in a column, say C4:C14. Then, select C4:C14
and array enter the formula =GetArray(A4:A14).

GetArray should look like:

Public Function GetArray(ByVal rng1 As Range)
Dim oSecret As Object

On Error GoTo ErrorHandler
Set oSecret = CreateObject("SomeDLL.Class")
getarray=application.worksheetfunction.transpose ( _
oSecret.GetSecretArray(rng1.Cells.Value))
ErrorHandler:
getarray=Err.Description
End Function

You can use application.caller to figure out if the range in which the
function is entered is a single row or a single column or something else
altogether and accordingly adjust the returned value. For example, if the
cells are contiguous in a single row then don't do the transpose.

--
An array formula is entered with CTRL-SHIFT-ENTER rather than just ENTER.
If done correctly, XL will display curly brackets { and } around the formula

Regards,

Tushar Mehta
www.tushar-mehta.com
Excel, PowerPoint, and VBA add-ins, tutorials
Custom MS Office productivity solutions

In article .com,
says...
Greetings All,

I am trying to understand why this function does not work. Any
suggestions would greatly be appreciated it.

Public Function GetArray(ByVal rng1 As Range, ByVal rng2 As Range) As
String
' rng1 is a 1-cell range; rng2 1-cell range
Dim vReturn As Variant
Dim oSecret As Object
Dim i As Integer

On Error GoTo ErrorHandler
Set oSecret = CreateObject("SomeDLL.Class")
vReturn = oSecret.GetSecretArray(rng1.Cells.Value)

GetArray = vbNullString
For i = 0 to UBound(vReturn) Step 1
GetArray = GetArray & vReturn(i) ' this is line is fine
rng2.Cells(i + 1).Value = vReturn(i) ' this line kicks the function
out; rng2.Offset(i) does not work either, rng2.<whatever.FormulaR1C1
does not help either
Next i
Exit Function
:ErrorHandler
MsgBox Err.Description
End Function


Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Conditional Sum without Range Parameters Peige414 Excel Worksheet Functions 5 October 22nd 08 05:55 PM
How can I sum a range using two parameters (eg location & date) Gory Excel Discussion (Misc queries) 2 July 1st 08 02:11 AM
change parameters of a range to be summed sevi61 Excel Worksheet Functions 2 September 9th 07 02:34 AM
Function Parameters Paddyk Setting up and Configuration of Excel 2 April 12th 05 08:52 AM
Count cells in one range based on parameters in another range dave roth Excel Worksheet Functions 2 March 29th 05 05:33 PM


All times are GMT +1. The time now is 09:42 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"