Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 4
Default join data in multiple cells when adjoining cells match criteria ??

This is DRIVING ME MAD.....
I have two workbooks. Workbook 1 is the final document which holds all the
information about our IT equipement from different areas. Workbook 2 shows
the PC number and the printers that it is assigned to.
What i am needed to do is show the printers that are shown in Workbook 2 in
Workbook 1 - but its not a simple concatenate.
In Workbook 2. Column A shows PC numbers, Column B shows the printers. If
more than one printer is assigned to a PC than the PC number will show
multiple times in Column A with the different printers in Column B. I am
needing to do a formula in Workbook 1 that says if the PC number in Workbook
1 matches any of the PC numbers in Workbook 2 then collect the printer data
in column B and concatenate to show in one cell.
Any ideas??????????
  #2   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 8,520
Default join data in multiple cells when adjoining cells match criteria ??

Thought I have responded to this post earlier...Try this UDF (User Defined
function). From workbook launch VBE using Alt+F11. From menu Insert a Module
and paste the below function.Close and get back to workbook and try the below
formula.

In your case the formula would be

Suppose sheet1 A1 is PC number
=VLOOKUP_CONCAT(Sheet2!A1:B1000,A1,2)

OR with delimiter char(10) so as to display each printer in separate line
within the cell
=VLOOKUP_CONCAT(Sheet2!A1:B1000,A1,2,char(10))


Syntax:
=VLOOKUP_CONCAT(rngRange,strLookupValue,intColumn, strDelimiter)

rngRange is the Range
strLookupValue is the lookup string or cell reference
inColumn is the column to be concatenated
strDelimiter Optional . Default is space

Examples:
'1. To vlookup 'jacob' and concatenate all entries of 2nd column
=VLOOKUP_CONCAT(A1:B10,"jacob",2)

'2. with lookup value in cell C1
=VLOOKUP_CONCAT(A1:B10,C1,2)

'3. with delimiter as comma
=VLOOKUP_CONCAT(A1:B10,C1,2,",")

Function VLOOKUP_CONCAT(rngRange As Range, _
strLookupValue As String, intColumn As Integer, _
Optional strDelimiter As String = " ")
Dim lngRow As Long
For lngRow = 1 To rngRange.Rows.Count
If CStr(rngRange(lngRow, 1)) = strLookupValue Then _
VLOOKUP_CONCAT = VLOOKUP_CONCAT & strDelimiter & _
rngRange(lngRow, intColumn)
Next
VLOOKUP_CONCAT = Mid(VLOOKUP_CONCAT, len(strDelimiter)+1)
End Function


If this post helps click Yes
---------------
Jacob Skaria


"angiec50" wrote:

This is DRIVING ME MAD.....
I have two workbooks. Workbook 1 is the final document which holds all the
information about our IT equipement from different areas. Workbook 2 shows
the PC number and the printers that it is assigned to.
What i am needed to do is show the printers that are shown in Workbook 2 in
Workbook 1 - but its not a simple concatenate.
In Workbook 2. Column A shows PC numbers, Column B shows the printers. If
more than one printer is assigned to a PC than the PC number will show
multiple times in Column A with the different printers in Column B. I am
needing to do a formula in Workbook 1 that says if the PC number in Workbook
1 matches any of the PC numbers in Workbook 2 then collect the printer data
in column B and concatenate to show in one cell.
Any ideas??????????

Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Countcells if they match certain criteria from other cells FormulaQuestioner Excel Discussion (Misc queries) 4 February 12th 08 03:06 AM
Adjoining Cells Carla Excel Worksheet Functions 1 December 11th 07 07:07 AM
Formula that compares data in adjoining cells Irv Excel Worksheet Functions 3 July 10th 07 11:44 PM
Adding up data in multiple cells for a single criteria. Philip Excel Worksheet Functions 1 April 5th 06 11:30 AM
3 criteria must exist in adjoining cells then rtn val from 4th SteveH Excel Discussion (Misc queries) 2 January 23rd 06 03:13 PM


All times are GMT +1. The time now is 02:23 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"