+ Reply to Thread
Results 1 to 3 of 3

Transform a too long Excel formula into a Macro

  1. #1
    Registered User
    Join Date
    08-16-2010
    Location
    Reggio Emilia, Italy
    MS-Off Ver
    Excel 2003
    Posts
    10

    Transform a too long Excel formula into a Macro

    Hi guys,
    I don't have any idea about Macros and i tried to make a really huge control only by using IF, COUNTIF and VLOOKUP functions.

    This is my biiiiig formula:

    =IF(COUNTIF(bom.XLS!$H:$H,"LBB *")>0, VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"BO *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"LBF *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"CON *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"TIE *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"AUX *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"INK FOIL *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"LB THERMAL *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"LB/P *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"LBT *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"SL *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"LBWR *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"CL *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"TP *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"CRC *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"FI *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),
    IF(COUNTIF(bom.XLS!$H:$H,"INK XE *")>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),"error")))))))))))))))))

    Excel message is "the formula is too long" but it's correct!

    Is someone able to create a macro that can do the same? I'm using Excel 2003

    Thank you very much!

    Ciao!

    Francesco

  2. #2
    Forum Expert Domski's Avatar
    Join Date
    12-14-2009
    Location
    A galaxy far, far away
    MS-Off Ver
    Darth Office 2010
    Posts
    3,950

    Re: Transform a too long Excel formula into a Macro

    Hi,

    Not vba but try:

    =IF(SUM(COUNTIF(bom.XLS!$H:$H,{"LBB *","BO *","LBF *","CON *","TIE *","AUX *","INK FOIL *","LB THERMAL *","LB/P *","LBT *","SL *","LBWR *","CL *","TP *","CRC *","FI *","INK XE *"}))>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),"error")

    Confirmed with Ctrl+Shift+Enter as it's an array formula.

    Dom
    "May the fleas of a thousand camels infest the crotch of the person who screws up your day and may their arms be too short to scratch..."

    Use code tags when posting your VBA code: [code] Your code here [/code]

    Remember, saying thanks only takes a second or two. Click the little star to give some Rep if you think an answer deserves it.

  3. #3
    Forum Expert contaminated's Avatar
    Join Date
    05-07-2009
    Location
    Baku, Azerbaijan
    MS-Off Ver
    Excel 2013
    Posts
    1,430

    Re: Transform a too long Excel formula into a Macro

    Try
    =IF(SUMPRODUCT((COUNTIF(bom.XLS!$H2:$H500,{"LBB *","BO *","LBF *","CON *","TIE *","AUX *","INK FOIL *","LB THERMAL *","LB/P *","LBT *","SL *","LBWR *","CL *","TP *","CRC *","FI *","INK XE *"})))>0,VLOOKUP(C18,IPS.xls!$E:$Q,13,FALSE),"Error")

    But you won't be able to pull data from a closed workbook with native excel function, despite of using INDIRECT. You will have to use Harlan's PULL function or INDIRECT.EXT from morefunc.xll
    Last edited by contaminated; 08-26-2010 at 10:55 AM.
    Люди, питающие благие намерения, как раз и становятся чудовищами.

    Regards, ?Born in USSR?
    Vusal M Dadashev

    Baku, Azerbaijan

+ 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