SOLVED

Switching/Opening worksheets across 2 workbooks

Brass Contributor

Hi, I have workbook1 and workbook2 each with 12 worksheets one for each month January, February etc....... I open workbook1 first and at some time open or switch, if it is already open, to workbook2 by using in a cell HYPERLINK("Quotation Unit Prices.xlsm"). Is there a way that i can open or switch to workbook2 in the same worksheet that i were in workbook1????

Thank You

Regards

11 Replies
best response confirmed by kobus1305 (Brass Contributor)
Solution

Hi @kobus1305,

 

Try this:

=HYPERLINK("[c:\test\excel\destination.xlsx]"&MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)&"!A1","destination")

 Obviously, you will need to change "c:\test\excel\destination.xlsx" for your path and your filename.

This will grab the sheet name you are currently in and will open the same sheet in your destination workbook.

@Bennadeau 

Hi, Thank you so much for your response. I do not think I have expressed the situation so very well. I am going to forward the workbook to you. You will see in column header "Open Quotation Unit Prices" is the hyperlinks on each worksheet. That means when workbook "Quotation Unit Prices" is opened that hyperlink knows on which worksheet it is and which worksheet to open on. My Hyperlink do not have a path name in it because the files is in the same directory on the hard drive. I just can not figure out how to format the Hyperlink function to accomplish it.

Regards

Thank You

@kobus1305 

Hi,

You sent "Quotation Program". I'm assuming you have another workbook named "Quotation unit price" somewhere, right? Sorry I'm a bit confused, I feel like I'm missing some info.

Either way, the following will give you the name of the current worksheet:

=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)

So, in my previous post, I concatenate it in the hyperlink formula. that way, if you are in workbook "ABC.xlsx", in sheet "august" the link will open workbook "DEF.xlsx" in sheet "august" You can remove the path for the filename if you want but leaving it there won't hurt. 

So, if you can send me the other missing file, tell me exactly where and in which workbook & worksheet you want the link to be (give me the actual cell. e.g."E1") I'll be able to better assist you.

@Bennadeau 

Hi,

I am confused to!!!!!When I am in workbook "Quotation Program.xlsm" on August worksheet and select the hyperlink "Hyperlink("Quotation Unit Prices .xlsm") to open or switch to "Quotation Unit Prices.xlsm"

how must the hyperlink looks like to also open on August worksheet in "Quotation Unit Prices.xlsm? The function do not have to go looking for which worksheet I am on. Each hyperlink function is formulated on each worksheet for that worksheet!

Regards

Thank You

@kobus1305 

ok, in Workbook "Quotation Program.xlsm", Sheet "August", type in this formula:

=HYPERLINK("[Quotation Unit Price.xlsm]"&MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)&"!A1","destination")

This will dynamically open "Quotation Unit Price.xlsm" in sheet "August".

 

If you don't want this to be dynamic, then use this formula:

=HYPERLINK("[Quotation Unit Price.xlsm]#August!A1","destination")

This will have the same end result as the previous formula but, you will need to modify, in the formula, "August" to whatever sheet you want to land in your workbook.

For example, if you want to land in the sheet named "June", your formula will look like this:

=HYPERLINK("[Quotation Unit Price.xlsm]#June!A1","destination")

Finally, the last "destination" in the formula is simply whatever will be presented on your sheet so you can type in whatever you want.

 

@Bennadeau 

Hi, Hell but you are an angel that is what i was looking for but could not figure it out, to use help you have to type just the right phrase to get help to give you more or less the correct info. I just could not figure out the #. Thank You so much

Regards

@kobus1305 

No problem, I'm glad we were able to find a solution.

Cheers!

@Bennadeau 

Hi, Sorry that is not what I meant. I can see your reasoning. The idea was a very different and good way!

I am sorry if I have offended you was not my idea. But thanks very much

Regards

 

@Bennadeau 

Hi Me again that works perfectly! One example I have in cell M4 HYPERLINK("[Quotation Unit Prices.xlsm]#January!G4","Open Unit Prices") on January worksheet of Quotation Program.xlsm workbook. There is 160 rows in each of this two workbooks. The idea is that if you are in cell M132 the hyperlink must land on cell G132 of january worksheet. If I copy M4 and paste the formula M5 to M160 the 4 in hyperlink do not count on from 5 to 160 because it is inside the quotes. Is there any way to formulate hyperlink to achieve my goal. I hope you understand???

Regards

Thank You

@kobus1305 

Try this...

HYPERLINK("[Quotation Unit Prices.xlsm]#January!G"&row(),"Open Unit Prices")

The "&row()" part will return the row where your hyperlink is located and append it in the formula right after "G" meaning that if your hyperlink is in cell "M111", the formula will automatically interprete the destination cell as "G111"

@Bennadeau  Hi, Thank You I played around with the row function but just could not formulate it correctly

Thank You so much

Regards

 

1 best response

Accepted Solutions
best response confirmed by kobus1305 (Brass Contributor)
Solution

Hi @kobus1305,

 

Try this:

=HYPERLINK("[c:\test\excel\destination.xlsx]"&MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)&"!A1","destination")

 Obviously, you will need to change "c:\test\excel\destination.xlsx" for your path and your filename.

This will grab the sheet name you are currently in and will open the same sheet in your destination workbook.

View solution in original post