Extracting information from records to another sheet automatically

  • Thread starter Thread starter Guest
  • Start date Start date
G

Guest

Dear experts,
I have a list of students with ten columns of data to the right and then an
eleventh column containing textual comments.

I want excel to automatically look at the range of student results
(A5:L300), determine which students have comments (not all students have
comments) and extract the student name and the comment and display this on
another sheet.

I can see how this can be done with an advanced filter however:
I want the results on another sheet and I don't want to have to do it
manually.

Is there any way I can achieve this?

kind regards
Molly
 
Actually, Advanced Filter can do what you want:

Here's an approach to try:
Assumptions:
Sheet1 contains your data in cells A5:L300
Sheet2 is where you want the extracted data to be displayed

Using Sheet2:
A1: StudentName
B1: Comment

Insert>Name>Define
Names in workbook: Sheet2!Extract
Refers to: =Sheet2!$A$1:$B$1

I1: Comment
I2: *

Insert>Name>Define
Names in workbook: Sheet2!Criteria
Refers to: =Sheet2!$I$1:$I$2

Still using Sheet2:
Insert>Name>Define
Names in workbook: Sheet2!Database
Refers to: =Sheet1!$A$5:$L$3000

(Notice: you are on Sheet2, and creating a Sheet2-level range name, but
the referenced range is on Sheet1)

The reason: An advanced filter cannot SEND data to another sheet, but
it can PULL data from another sheet.

Now...set up the Advanced Data Filter:
Data>Filter>Advanced Data Filter
Select: Copy to another location
List Range: (press F3 and select Database)
Criteria Range: (press F3 and select Criteria)
Copy To: (press F3 and select Extract)
Click [OK]

Note: if you want to run that Advanced Data Filter repeatedly,
you'll need to re-select Database each time
.....OR...if you're feeling a bit ambitious...

You can build a simple macro to automatically re-run the filter:
Press [Alt]+[F11] to open the VBA editor
Right click on the VBA Project folder for your workbook
Select: Insert>Module

Then, copy/paste this code into that module:

'---Start of Code-------
Option Explicit
Sub PullMatchingData()
Range("Sheet2!Database").AdvancedFilter _
Action:=xlFilterCopy, _
CriteriaRange:=Range("Sheet2!Criteria"), _
CopyToRange:=Range("Sheet2!Extract"), _
Unique:=False
End Sub
'---Start of Code-------

To run the code:
Tools>Macro>Macros (or [Alt]+[F8])
Select and run: PullMatchingData

To test, change the value of I2 and run it again.


Does that help?

***********
Regards,
Ron

XL2002, WinXP-Pro
 
Thank you so much. I am very grateful for your willingness to share your
expertise.
Many thanks
Molly

Ron Coderre said:
Actually, Advanced Filter can do what you want:

Here's an approach to try:
Assumptions:
Sheet1 contains your data in cells A5:L300
Sheet2 is where you want the extracted data to be displayed

Using Sheet2:
A1: StudentName
B1: Comment

Insert>Name>Define
Names in workbook: Sheet2!Extract
Refers to: =Sheet2!$A$1:$B$1

I1: Comment
I2: *

Insert>Name>Define
Names in workbook: Sheet2!Criteria
Refers to: =Sheet2!$I$1:$I$2

Still using Sheet2:
Insert>Name>Define
Names in workbook: Sheet2!Database
Refers to: =Sheet1!$A$5:$L$3000

(Notice: you are on Sheet2, and creating a Sheet2-level range name, but
the referenced range is on Sheet1)

The reason: An advanced filter cannot SEND data to another sheet, but
it can PULL data from another sheet.

Now...set up the Advanced Data Filter:
Data>Filter>Advanced Data Filter
Select: Copy to another location
List Range: (press F3 and select Database)
Criteria Range: (press F3 and select Criteria)
Copy To: (press F3 and select Extract)
Click [OK]

Note: if you want to run that Advanced Data Filter repeatedly,
you'll need to re-select Database each time
....OR...if you're feeling a bit ambitious...

You can build a simple macro to automatically re-run the filter:
Press [Alt]+[F11] to open the VBA editor
Right click on the VBA Project folder for your workbook
Select: Insert>Module

Then, copy/paste this code into that module:

'---Start of Code-------
Option Explicit
Sub PullMatchingData()
Range("Sheet2!Database").AdvancedFilter _
Action:=xlFilterCopy, _
CriteriaRange:=Range("Sheet2!Criteria"), _
CopyToRange:=Range("Sheet2!Extract"), _
Unique:=False
End Sub
'---Start of Code-------

To run the code:
Tools>Macro>Macros (or [Alt]+[F8])
Select and run: PullMatchingData

To test, change the value of I2 and run it again.


Does that help?

***********
Regards,
Ron

XL2002, WinXP-Pro


Molly said:
Dear experts,
I have a list of students with ten columns of data to the right and then an
eleventh column containing textual comments.

I want excel to automatically look at the range of student results
(A5:L300), determine which students have comments (not all students have
comments) and extract the student name and the comment and display this on
another sheet.

I can see how this can be done with an advanced filter however:
I want the results on another sheet and I don't want to have to do it
manually.

Is there any way I can achieve this?

kind regards
Molly
 
Back
Top