Please Help

Gipy

New Member
Joined
Sep 15, 2011
Messages
8
Hi All,

I have a formula that returns the name of the current worksheet if any of the other worksheets have a B8 cell that equals TEST, this can be seen below:

=IF(SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!"&CELL("address",B8)),"=TEST")),MID(CELL("filename"),FIND("]",CELL("filename"))+1,255),"NO")

This returns the name of the worksheet that holds this formula instead of the worksheet that has the B8 cell that has the text TEST in it.


I need the worksheet (or worksheets) name(s) returned for any of the worksheet(s) that meets this condition.

Any help would be much appreciated.

Thanks Gipy.
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
Hi All,

I have a formula that returns the name of the current worksheet if any of the other worksheets have a B8 cell that equals TEST, this can be seen below:

=IF(SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!"&CELL("address",B8)),"=TEST")),MID(CELL("filename"),FIND("]",CELL("filename"))+1,255),"NO")

This returns the name of the worksheet that holds this formula instead of the worksheet that has the B8 cell that has the text TEST in it.


I need the worksheet (or worksheets) name(s) returned for any of the worksheet(s) that meets this condition.

Any help would be much appreciated.

Thanks Gipy.
Since you apparently already have a range that lists the sheet names why not do something simple like this:

Book1
AB
2Sheet1NO
3Sheet2NO
4Sheet3Sheet3
5Sheet4NO
Sheet1

This formula entered in B2 and copied down:

=IF(INDIRECT("'"&A2&"'!B8")="TEST",A2,"NO")
 
Upvote 0
As my Excel skills are pretty poor, I'll explain the problem I am trying to solve.

Each support assistant and pupil will have a timetable. When a certain support assistant's name is entered into a day and period on a pupil's timetable, the corresponding pupils name (which will be somewhere on each pupil's timetable) needs to populate onto the support assistant's timetable.

The ideal scenario would also not allow a support assistant to be entered onto the same day and period for more than one pupil.

Any help would be most appreciated.

Gipy.
 
Upvote 0
As my Excel skills are pretty poor, I'll explain the problem I am trying to solve.

Each support assistant and pupil will have a timetable. When a certain support assistant's name is entered into a day and period on a pupil's timetable, the corresponding pupils name (which will be somewhere on each pupil's timetable) needs to populate onto the support assistant's timetable.

The ideal scenario would also not allow a support assistant to be entered onto the same day and period for more than one pupil.

Any help would be most appreciated.

Gipy.
So, how does this description relate to your original question?

Here's how I interpret what you wrote:

On some sheet in some range there might be some name. If that name is present enter that name on some other sheet.

Kind of light on the details, don't'cha think?
 
Upvote 0
Hi, Thanks for your interest.

I thought that the formula, I bodged together, might let me know if a variable was entered into a certain cell on another worksheet (this variable would match the worksheet the formula was on) and show that worksheet name. The formula originally entered in this thread, I thought, did this in part and in my naivety thought that if my original question was answered, I could get a bit closer to getting this task sorted. As people posted their reply s I came to the conclusion that I should have just posted the main task I was trying to complete, which I did in my last post.
Thank you for your interest and if you can help me with this timetable problem I would appreciate your help.

The task in hand:-
"My Excel skills are pretty poor and I am trying to implement a timetable system to do the following:

Each support assistant and pupil will have a timetable (in one workbook but on separate worksheets) . When a certain support assistant's name is entered into a day and period on a pupil's timetable, the corresponding pupils name (which will be somewhere on each pupil's timetable) needs to populate onto the support assistant's timetable.

The ideal scenario would also not allow a support assistant to be entered onto the same day and period for more than one pupil.

Any help would be most appreciated, (please remember I am a Excel newbie!)
"


Thanks again.
 
Upvote 0
Hi All,

I have a formula that returns the name of the current worksheet if any of the other worksheets have a B8 cell that equals TEST, this can be seen below:

=IF(SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!"&CELL("address",B8)),"=TEST")),MID(CELL("filename"),FIND("]",CELL("filename"))+1,255),"NO")

This returns the name of the worksheet that holds this formula instead of the worksheet that has the B8 cell that has the text TEST in it.


I need the worksheet (or worksheets) name(s) returned for any of the worksheet(s) that meets this condition.

Any help would be much appreciated.

Thanks Gipy.
Suppose we have 3 relevant sheets: Sheet2, Sheet3, and Sheet4.

Let Sheet2!B8 and Sheet4!B8 house the string TEST.

Let Sheet1 house the processing...

<TABLE style="WIDTH: 144pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=192><COLGROUP><COL style="WIDTH: 48pt" span=3 width=64><TBODY><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 48pt; HEIGHT: 14.4pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl64 height=19 width=64>Sheet List</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 48pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 width=64></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 48pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 width=64 align=right>2</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19>Sheet2</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63>Sheet2</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19>Sheet3</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63>Sheet4</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19>Sheet4</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63></TD></TR></TBODY></TABLE>

A2:A4 houses the list of the relevant sheets and it's named MySheets via the Name Box on the Formula Bar.

C1:
Code:
=SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!B8"),"TEST"))

This counts the sheets housing TEST in their B8 cell. The following formula retrieves the names of those sheets...

C2, control+shift+enter, not just enter, and copy down:
Code:
=IF(ROWS($C$2:C2)<=$C$1,INDEX(MySheets,
SMALL(IF(COUNTIF(INDIRECT("'"&MySheets&"'!B8"),"TEST"),
ROW(INDIRECT("1:"&COUNTA(MySheets)))),ROWS($C$2:C2))),"")
 
Upvote 0
Hi, Thanks for your interest.

I thought that the formula, I bodged together, might let me know if a variable was entered into a certain cell on another worksheet (this variable would match the worksheet the formula was on) and show that worksheet name. The formula originally entered in this thread, I thought, did this in part and in my naivety thought that if my original question was answered, I could get a bit closer to getting this task sorted. As people posted their reply s I came to the conclusion that I should have just posted the main task I was trying to complete, which I did in my last post.
Thank you for your interest and if you can help me with this timetable problem I would appreciate your help.

The task in hand:-
"My Excel skills are pretty poor and I am trying to implement a timetable system to do the following:

Each support assistant and pupil will have a timetable (in one workbook but on separate worksheets) . When a certain support assistant's name is entered into a day and period on a pupil's timetable, the corresponding pupils name (which will be somewhere on each pupil's timetable) needs to populate onto the support assistant's timetable.

The ideal scenario would also not allow a support assistant to be entered onto the same day and period for more than one pupil.

Any help would be most appreciated, (please remember I am a Excel newbie!)"


Thanks again.
Sorry, still not clear.

Is this what you want or am I not even close:

Here's how I interpret what you wrote:

On some sheet in some range there might be some name. If that name is present enter that name on some other sheet.

Kind of light on the details, don't'cha think?
 
Upvote 0
Thanks for your replies, I am not sure how to implement your suggestion Aladin, so I have included a screen shot of my timetable in Excel. If you could let me know which cell to put thinks in that would be great.

http://www.webattic-development.co.uk/cards.html

-- removed inline image ---



T. Valko, thanks for sticking with me.

Suppose the above timetable is for one of the Support Assistants within the the school and is on one of many worksheets made up of initially support assistants and then pupils that need support in lessons. There could be over one hundred worksheets within this workbook. When I enter the the support assistants name on a pupils timetable for a given period I need the pupils name to appear of the support assistants timetable. It would be nice if the system could also stop me from double booking support assistants time.
If you understand this scenario/problem any solution in layman's terms would be great.

Thank you both again.

Gipy.
 
Last edited:
Upvote 0
Thanks for your replies, I am not sure how to implement your suggestion Aladin, so I have included a screen shot of my timetable in Excel. If you could let me know which cell to put thinks in that would be great.

http://www.webattic-development.co.uk/cards.html

...

The description I gave is pretty much self-contained. You can implement it in a new workbook and evaluate the set up if it's usable for your real problem.
 
Upvote 0
I did some tests with the Aladin's formula and it worked here. Look at this:

Excel 2007<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2><COLGROUP><COL style="BACKGROUND-COLOR: #e0e0f0" width=25><COL><COL></COLGROUP><THEAD><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH></TH><TH>A</TH><TH>B</TH></TR></THEAD><TBODY><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">1</TD><TD style="TEXT-ALIGN: center">Master</TD><TD style="TEXT-ALIGN: center">Sheet1</TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">2</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center">Sheet3</TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">3</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">4</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">5</TD><TD style="TEXT-ALIGN: center">******</TD><TD style="TEXT-ALIGN: center">******</TD></TR></TBODY></TABLE>Master


<TABLE style="BORDER-BOTTOM: black 2px solid; BORDER-LEFT: black 2px solid; PADDING-BOTTOM: 0.4em; BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 0.4em; PADDING-RIGHT: 0.4em; BORDER-COLLAPSE: collapse; BORDER-TOP: black 2px solid; BORDER-RIGHT: black 2px solid; PADDING-TOP: 0.4em" rules=all cellPadding=2 width="85%"><TBODY><TR><TD style="PADDING-BOTTOM: 6px; PADDING-LEFT: 6px; PADDING-RIGHT: 6px; PADDING-TOP: 6px">Worksheet Formulas<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; TEXT-ALIGN: center; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2 width="100%"><THEAD><TR style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH width=10>Cell</TH><TH style="TEXT-ALIGN: left; PADDING-LEFT: 5px">Formula</TH></TR></THEAD><TBODY><TR><TH style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120" width=10>A1</TH><TD style="TEXT-ALIGN: left">=IF(SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!B8"),"TEST")),MID(CELL("nome.arquivo"),FIND("]",CELL("nome.arquivo"))+1,255),"NO")</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM: black 2px solid; BORDER-LEFT: black 2px solid; PADDING-BOTTOM: 0.4em; BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 0.4em; PADDING-RIGHT: 0.4em; BORDER-COLLAPSE: collapse; BORDER-TOP: black 2px solid; BORDER-RIGHT: black 2px solid; PADDING-TOP: 0.4em" rules=all cellPadding=2 width="85%"><TBODY><TR><TD style="PADDING-BOTTOM: 6px; PADDING-LEFT: 6px; PADDING-RIGHT: 6px; PADDING-TOP: 6px">Array Formulas<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; TEXT-ALIGN: center; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2 width="100%"><THEAD><TR style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH width=10>Cell</TH><TH style="TEXT-ALIGN: left; PADDING-LEFT: 5px">Formula</TH></TR></THEAD><TBODY><TR><TH style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120" width=10>B1</TH><TD style="TEXT-ALIGN: left">{=IF(SUMPRODUCT(COUNTIF(INDIRECT("'"&MySheets&"'!B8"),"TEST"))>=ROWS(B$1:B1),
INDEX(MySheets,SMALL(IF(COUNTIF(INDIRECT("'"&MySheets&"'!B8"),"TEST"),ROW(INDIRECT("$1:$"&COUNTA(MySheets)))),ROWS(B$1:B1))),""
)}

</TD></TR></TBODY></TABLE>Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

</TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM: black 2px solid; BORDER-LEFT: black 2px solid; PADDING-BOTTOM: 0.4em; BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 0.4em; PADDING-RIGHT: 0.4em; BORDER-COLLAPSE: collapse; BORDER-TOP: black 2px solid; BORDER-RIGHT: black 2px solid; PADDING-TOP: 0.4em" rules=all cellPadding=2 width="85%"><TBODY><TR><TD style="PADDING-BOTTOM: 6px; PADDING-LEFT: 6px; PADDING-RIGHT: 6px; PADDING-TOP: 6px">Workbook Defined Names<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; TEXT-ALIGN: center; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2 width="100%"><THEAD><TR style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH width=10>Name</TH><TH style="TEXT-ALIGN: left">Refers To</TH></TR></THEAD><TBODY><TR><TH style="BACKGROUND-COLOR: #e0e0f0; COLOR: #161120" width=10>MySheets</TH><TD style="TEXT-ALIGN: left">={"Sheet1";"Sheet2";"Sheet3";"Sheet4"}</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>


Excel 2007<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2><COLGROUP><COL style="BACKGROUND-COLOR: #e0e0f0" width=25><COL><COL></COLGROUP><THEAD><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH></TH><TH>A</TH><TH>B</TH></TR></THEAD><TBODY><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">1</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">2</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">3</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">4</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">5</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">6</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">7</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">8</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center">TEST</TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">9</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">10</TD><TD style="TEXT-ALIGN: center">******</TD><TD style="TEXT-ALIGN: center">******</TD></TR></TBODY></TABLE>Sheet1

Excel 2007<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2><COLGROUP><COL style="BACKGROUND-COLOR: #e0e0f0" width=25><COL><COL></COLGROUP><THEAD><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH></TH><TH>A</TH><TH>B</TH></TR></THEAD><TBODY><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">1</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">2</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">3</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">4</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">5</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">6</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">7</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">8</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">9</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">10</TD><TD style="TEXT-ALIGN: center">******</TD><TD style="TEXT-ALIGN: center">******</TD></TR></TBODY></TABLE>Sheet2

Excel 2007<TABLE style="BORDER-BOTTOM: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BACKGROUND-COLOR: #ffffff; BORDER-COLLAPSE: collapse; BORDER-TOP: #a6aab6 1px solid; BORDER-RIGHT: #a6aab6 1px solid" rules=all cellPadding=2><COLGROUP><COL style="BACKGROUND-COLOR: #e0e0f0" width=25><COL><COL></COLGROUP><THEAD><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #e0e0f0; COLOR: #161120"><TH></TH><TH>A</TH><TH>B</TH></TR></THEAD><TBODY><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">1</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">2</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">3</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">4</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">5</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">6</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">7</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">8</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center">TEST</TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">9</TD><TD style="TEXT-ALIGN: center"></TD><TD style="TEXT-ALIGN: center"></TD></TR><TR><TD style="TEXT-ALIGN: center; COLOR: #161120">10</TD><TD style="TEXT-ALIGN: center">******</TD><TD style="TEXT-ALIGN: center">******</TD></TR></TBODY></TABLE>Sheet3

I hope this help you.



Markmzz
 
Upvote 0

Forum statistics

Threads
1,224,522
Messages
6,179,299
Members
452,904
Latest member
CodeMasterX

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