Consulting

Results 1 to 11 of 11

Thread: Let and Lambda

  1. #1
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,446
    Location

    Let and Lambda

    I have to admit that, whilst I am not convinced that these are the way to go for Excel (most Excel users don't want to 'program' Excel, and most 'useful' Lambda functions that I see are pretty complex, and I find that I struggle to understand Lambda functions that I wrote when I revisit them), I am using them an awful amount in my own workbooks.

    One thing I especially like to do with Let formulae is to declare my variables up top, rather than in the body of the function. In a very simple example, rather than
    =LET(res, FILTER($A$1:$A$500, $B$1:$B$500="Transfer"),
             res)
    I would write
    =LET(method, "Transfer",
             res, FILTER($A$1:$A$500, $B$1:$B$500=method),
             res)
    One issue I have come up against though is that I don't see to be able to setup a table variable in this way. Take this example formula
    =LET(tx, tblTransactions,
              method, "Transfer",
              tx_date, TODAY(),
              res, FILTER(tx[Date], (tx[Method]=method)*(tx[Date]>=tx_date)),
              res)
    I could use INDIRECT for the table, but I don't want to do that.

    I could also define each of the table columns separately and reference those, but I was wanting to have a single point defining the table.
    Does anyone else have this issue? Has anyone cracked it.
    Last edited by Bob Phillips; 04-02-2024 at 09:15 AM.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  2. #2
    Administrator VBAX Master georgiboy's Avatar
    Joined
    Mar 2008
    Location
    Kent, England
    Posts
    1,256
    Location
    Not sure you can refer to a column in a table you have defined like 'tx[Date]'

    If you define the table, in my mind it becomes more of a range to the LET formula, as such you can refer to the columns with Index:
    =LET(tx, tblTransactions,
              method, "Transfer",
              tx_date, TODAY(),
              res, FILTER(INDEX(tx,,1), (INDEX(tx,,2)=method)*(INDEX(tx,,1)>=tx_date)),
              res)
    Other than that you would use the table name itself:
    =LET(method, "Transfer",
              tx_date, TODAY(),
              res, FILTER(tblTransactions[Date], (tblTransactions[Method]=method)*(tblTransactions[Date]>=tx_date)),
              res)
    If you renamed the table 'tx' then 'tx[Date]' would be fine.
    Attached Files Attached Files
    Click here for a guide on how to add code tags
    Click here for a guide on how to mark a thread as solved
    Click here for a guide on how to upload a file with your post

    Excel 365, Version 2408, Build 17928.20080

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,446
    Location
    Quote Originally Posted by georgiboy View Post
    If you define the table, in my mind it becomes more of a range to the LET formula
    You may be right there, but if so that is poor implementation of LET in my view. As with other instances, CF, row grouping, for example, the Excel guys have added functionality without consideringfor tables, even though they are pushing tables as the way to go.

    Quote Originally Posted by georgiboy View Post
    , as such you can refer to the columns with Index:
    =LET(tx, tblTransactions,
              method, "Transfer",
              tx_date, TODAY(),
              res, FILTER(INDEX(tx,,1), (INDEX(tx,,2)=method)*(INDEX(tx,,1)>=tx_date)),
              res)
    No, that is horrible. It is referring to columns in the table by position not by name, which is wholly at odds with the rationale of structured tables.

    Quote Originally Posted by georgiboy View Post
    Other than that you would use the table name itself:
    =LET(method, "Transfer",
              tx_date, TODAY(),
              res, FILTER(tblTransactions[Date], (tblTransactions[Method]=method)*(tblTransactions[Date]>=tx_date)),
              res)
    That is exactly what I am doing now, but that means that I reference the table name 3 times rather than just once, not good coding practice.

    Quote Originally Posted by georgiboy View Post
    If you renamed the table 'tx' then 'tx[Date]' would be fine.
    No way! I have very clearly defined coding standards
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  4. #4
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,234
    Location
    hehehe.... ze English are firing upon themselves. I shall make my escape into the darkness.
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  5. #5
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,787
    Location
    Quote Originally Posted by Aussiebear View Post
    hehehe.... ze English are firing upon themselves. I shall make my escape into the darkness.
    Us colonials will also make our escape to the familar land of VBA and UDFs
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  6. #6
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,446
    Location
    It's all friendly guys, or to use a horrible phrase, just banter. Georgiboy basically confirmed what I thought, I can't have my cake and eat it .
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  7. #7
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,234
    Location
    So was ours Bob. Must admit it is good to see you here.
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  8. #8
    Administrator VBAX Master georgiboy's Avatar
    Joined
    Mar 2008
    Location
    Kent, England
    Posts
    1,256
    Location
    It is indeed good to see you back Bob, I did learn a lot from your posts years ago...

    It's all friendly guys
    It was taken as such, you are as frustrated as me at the way Excel has progressed.

    You may be right there, but if so that is poor implementation of LET in my view. As with other instances, CF, row grouping, for example, the Excel guys have added functionality without considering for tables, even though they are pushing tables as the way to go.
    I can only agree, another annoying issue is that you can't use array formulae in a table, the formulae are unable to expand the table, this is but another missed opportunity.

    No, that is horrible. It is referring to columns in the table by position not by name, which is wholly at odds with the rationale of structured tables.
    Again I agree, however, this is the method I use quite a bit, only on tables where I know the structure of the table will not change.

    That is exactly what I am doing now, but that means that I reference the table name 3 times rather than just once, not good coding practice.
    No way! I have very clearly defined coding standards
    Again I have to agree, however, this is not technically "Coding" by my own definition
    Click here for a guide on how to add code tags
    Click here for a guide on how to mark a thread as solved
    Click here for a guide on how to upload a file with your post

    Excel 365, Version 2408, Build 17928.20080

  9. #9
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,779
    Location
    Quote Originally Posted by Bob Phillips View Post
    You may be right there, but if so that is poor implementation of LET in my view.
    I don't see that as anything to do with LET though. LET is basically just a formula version of Dim (or indeed Let in M code). The limitation is just a(nother) limitation of tables, as you say. To refer to columns by name, either in LET or any other formula, you need to use INDIRECT or match the name in the headers to get a column number to use in INDEX.
    Be as you wish to seem

  10. #10
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,446
    Location
    Even Rory is still here, it is almost like the old days, but with more Excel gizmos!

    Quote Originally Posted by Aflatoon View Post
    I don't see that as anything to do with LET though. LET is basically just a formula version of Dim (or indeed Let in M code). The limitation is just a(nother) limitation of tables, as you say. To refer to columns by name, either in LET or any other formula, you need to use INDIRECT or match the name in the headers to get a column number to use in INDEX.
    I agree that it is, but LET in Excel had to be built (coded), and if they had thought about it I am sure those guys are plenty smart enough to have catered for a full table reference. You can reference a table in VBA, you can reference a table in M, but not it seems in Excel.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  11. #11
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,779
    Location
    You can get a table reference, you just can't refer to columns by name using variables, without the use of INDIRECT or INDEX/MATCH or similar. LET doesn't change the way range referencing or other functions work. Or did I miss your point? Your original formula was basically the equivalent of putting a column name in a cell then trying to use that to refer to a table column - e.g. tblTransactions[A2] - and that won't work with or without LET. If they were going to make LET change the way functions operated, I'd much rather they'd made all the xxxIF(S) functions work with the intermediate arrays you always seem to end up with when using LET, LAMBDA et al!
    Be as you wish to seem

Posting Permissions

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