Microsoft Office Forums

Go Back   Microsoft Office Forums > >

Reply
 
Thread Tools Display Modes
  #1  
Old 08-04-2015, 04:46 AM
tinfanide tinfanide is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 32bit
Expert
Excel table: refer to a particular row?
 
Join Date: Aug 2011
Posts: 312
tinfanide is on a distinguished road
Default Excel table: refer to a particular row?

Excel Table - refer to a particular row.xlsx

In the file attached, in sheet 1, there is a table (Table 1) with a column of names.

In sheet 2, there is also a table (Table 2) with a column of same names.
I would like to in sheet 1 have a column (below) to count a particular row if there is any blank cell in that row. For example, the person "f" in Table 2 has two blank cells and in Table 1, the column "Count" for person "f" should be 2 (actually is now).

But when I have a different sort in Table 1, the Countif formula in Table 1 does not follow the person "f". As a result, the Count result for each person in Table 1 is wrong.



Code:
=COUNTIF(Table2[@],"")
Please see the attached file for the whole picture.
Any help is appreciated.
Reply With Quote
  #2  
Old 08-04-2015, 07:05 AM
gebobs gebobs is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Mar 2014
Location: Atlanta
Posts: 837
gebobs has a spectacular aura aboutgebobs has a spectacular aura about
Default

What your formula is doing is counting the number of blanks in the row in Table2 corresponding to the row in Table1. If the the data in the first columns of either table differ at all, you will not get the correct result.

The simplest solution would be to combine the tables. I understand your sample is likely a very simple example of your actual tables so it might be cumbersome. But as it is, both tables appear to have the same primary key i.e. the testees' names and thus theoretically would work.

There's certainly a way to do it the way you have it set up now, but I can't think of it. I'll ponder it.
Reply With Quote
  #3  
Old 08-04-2015, 07:11 AM
tinfanide tinfanide is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 32bit
Expert
Excel table: refer to a particular row?
 
Join Date: Aug 2011
Posts: 312
tinfanide is on a distinguished road
Default

Yes, your guess is right. The reason behind is I cannot merge the two tables.

Table 2 is a large database. Table 1 is a summary table. More I would like to do is to highlight the names (e.g. person "f" and person "u") based on their empty records on Table 2.
Reply With Quote
  #4  
Old 08-04-2015, 07:17 AM
gebobs gebobs is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Mar 2014
Location: Atlanta
Posts: 837
gebobs has a spectacular aura aboutgebobs has a spectacular aura about
Default

OK...I was able to kludge together a formula that does it and is sortable. See attached.
Attached Files
File Type: xlsx Excel Table - refer to a particular row.xlsx (11.3 KB, 9 views)
Reply With Quote
  #5  
Old 08-04-2015, 07:37 AM
tinfanide tinfanide is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 32bit
Expert
Excel table: refer to a particular row?
 
Join Date: Aug 2011
Posts: 312
tinfanide is on a distinguished road
Default

Quote:
Originally Posted by gebobs View Post
OK...I was able to kludge together a formula that does it and is sortable. See attached.
Yes. While using MATCH to get the absolute row numbers, I was thinking of how to reference using those row numbers with Table. Your use of ADDRESS and INDIRECT is really insightful.

Many thanks for your help!
Reply With Quote
  #6  
Old 08-04-2015, 08:19 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,790
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

To avoid volatile functions you can also use a little known (or rarely used) property of the INDEX function in D2

Code:
=COUNTBLANK(INDEX(Table2[#All],MATCH(Table1[[#This Row],[Name]],Table2[Name],0)+1,))
The extra comma force the INDEX function to return the entire corresponding row
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #7  
Old 08-04-2015, 10:42 PM
tinfanide tinfanide is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 32bit
Expert
Excel table: refer to a particular row?
 
Join Date: Aug 2011
Posts: 312
tinfanide is on a distinguished road
Default

Quote:
Originally Posted by gebobs View Post
OK...I was able to kludge together a formula that does it and is sortable. See attached.
By the way, I'd like to ask
Code:
' no error
=COUNTBLANK(INDIRECT("Sheet2!"&ADDRESS(MATCH(A2,Table2[Name],0)+1,2)&":"&ADDRESS(MATCH(A2,Table2[Name],0)+1,4)))

' return #REF
=COUNTBLANK(INDIRECT("Sheet2!"&ADDRESS(MATCH(A2,Table2[Name],0)+1,2)&":"&"Sheet2!"&ADDRESS(MATCH(A2,Table2[Name],0)+1,4)))

' Sheet2!B2:D2 (1st formula's result)
' Sheet2!B2:Sheet2!D2 (2nd formula's result)
' They should be the same (as a range)

Last edited by tinfanide; 08-05-2015 at 04:01 AM.
Reply With Quote
  #8  
Old 08-05-2015, 12:21 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,790
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

Your second version would return something like ...sheet2!cell_ref:sheet2!another_ref were it should be sheet2!cell_ref:another_ref
Try the " examine formula" wizard to it at work
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #9  
Old 08-05-2015, 04:15 AM
tinfanide tinfanide is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 32bit
Expert
Excel table: refer to a particular row?
 
Join Date: Aug 2011
Posts: 312
tinfanide is on a distinguished road
Default

Quote:
Originally Posted by Pecoflyer View Post
Your second version would return something like ...sheet2!cell_ref:sheet2!another_ref were it should be sheet2!cell_ref:another_ref
Try the " examine formula" wizard to it at work
Yes, I see. Thanks.
Reply With Quote
  #10  
Old 08-05-2015, 04:57 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,790
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

Glad to help. And please, in the future don't quote whole posts -- it's just clutter. If you are responding to a post out of sequence, limit quoted content to a few relevant lines that makes clear to whom and what you are responding.
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #11  
Old 08-05-2015, 01:17 PM
gebobs gebobs is offline Excel table: refer to a particular row? Windows 7 64bit Excel table: refer to a particular row? Office 2010 64bit
Expert
 
Join Date: Mar 2014
Location: Atlanta
Posts: 837
gebobs has a spectacular aura aboutgebobs has a spectacular aura about
Default

Damn yer good Peco!
Reply With Quote
Reply



Similar Threads
Thread Thread Starter Forum Replies Last Post
Insert a Excel table in an existing PowerPoint table Vallin PowerPoint 1 03-09-2015 06:25 AM
Excel table: refer to a particular row? If (C1 = refer to a cell in a range) then (show the description in C2) & (corresponding price in C3) lily Excel 9 10-23-2014 06:21 AM
How to change the path of a table copied by excel in word as linked table RTF? Cristin7 Word VBA 3 03-10-2014 05:25 AM
update one embedded excel table based on another excel table ajetrumpet Word 0 07-05-2013 08:51 PM
How do I refer to page numbers, when the numbers change as I prepare the document? StevenD Word 5 11-29-2012 12:52 AM

Other Forums: Access Forums

All times are GMT -7. The time now is 11:11 PM.


Powered by vBulletin® Version 3.8.11
Copyright ©2000 - 2024, vBulletin Solutions Inc.
Search Engine Optimisation provided by DragonByte SEO (Lite) - vBulletin Mods & Addons Copyright © 2024 DragonByte Technologies Ltd.
MSOfficeForums.com is not affiliated with Microsoft