How to arrange data accordingly from different excel worksheet?

azrul94

New Member
Joined
Sep 7, 2017
Messages
1
Dear all,
Sorry for asking this question because I'm very new in understanding excel and I'm not a computer expertise.
I was given a task which contains about 20 thousands of data and have to arrange it accordingly to its ID.
I'm not very good at the words in excel so much, so I here i attach the example of what I have to do.
PjIcZv7


Excel 1
[TABLE="width: 200"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]ID[/TD]
[TD]FUNCTION[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]S1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]S2[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]S6[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]S10[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]S10[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]S20[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]S21[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]S22[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]S22[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]S23[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

Excel 2
[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]ID[/TD]
[TD]NAME[/TD]
[TD]FUNCTION[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]S1[/TD]
[TD]SAM[/TD]
[TD]SLEEP[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]S2[/TD]
[TD]LILY[/TD]
[TD]WALK[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]S3[/TD]
[TD]SIM[/TD]
[TD]SPEAK[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]S5[/TD]
[TD]ROBERT[/TD]
[TD]RUN[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]S7[/TD]
[TD]WILLIAM[/TD]
[TD]SWIM[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]S10[/TD]
[TD]BETTY[/TD]
[TD]EAT[/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]S11[/TD]
[TD]ANNA[/TD]
[TD]CYCLING[/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]S12[/TD]
[TD]DANNY[/TD]
[TD]ANGRY[/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]S23[/TD]
[TD]DORY[/TD]
[TD]SAD[/TD]
[/TR]
</tbody>[/TABLE]

As you can see, the data that i need to transfer and arrange accordingly from Excel 2 to Excel 1 is the FUNCTION. But not all ID in Excel 1 is in Excel 2, same goes to not all ID in Excel 2 is in Excel 1. In Excel 1 the ID can be redundant, example: A5 with A6 and A9 with A10. Moreover, NAME are not required in Excel 1.

The result that I should get by transferring and arranging the data are as follows:
PjIcZv7


Excel 1
[TABLE="width: 200"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]ID[/TD]
[TD]FUNCTION[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]S1[/TD]
[TD]SLEEP[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]S2[/TD]
[TD]WALK[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]S6[/TD]
[TD]NA[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]S10[/TD]
[TD]EAT[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]S10[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]S20[/TD]
[TD]NA[/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]S21[/TD]
[TD]NA[/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]S22[/TD]
[TD]NA[/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]S22[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]S23[/TD]
[TD]SAD[/TD]
[/TR]
</tbody>[/TABLE]

The NA stands for not available. When the data comes to the redundant there will be blank space as example: A6 and A10. My data came in bulk that already consume my time for copy and paste one-by-one. If anyone could help me to sort this out by using any formula or anything? Im sorry for troubling you guys. If there is already thread like this can you guys link it?
Thank you so much.
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
azrul94,

Welcome to the MrExcel forum.

Here is a macro solution for you to consider that is based on your three flat text displays.


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub azrul94()
' hiker95, 09/08/2017, ME1021885
Application.ScreenUpdating = False
Dim w1 As Worksheet, w2 As Worksheet
Dim r As Range, a As Range, rng As Range, n As Long
Set w1 = Sheets("Excel 1")
Set w2 = Sheets("Excel 2")
With w1
  For Each r In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
    Set rng = .Range("A2:A" & r.Row)
    n = Application.CountIf(rng, r)
    If n > 1 Then
      'do nothing
      GoTo Continue
    Else
      Set a = w2.Columns(1).Find(r.Value, LookAt:=xlWhole)
      If a Is Nothing Then
        r.Offset(, 1) = "NA"
      ElseIf Not a Is Nothing Then
        r.Offset(, 1).Value = a.Offset(, 2).Value
      End If
    End If
Continue:
  Next r
End With
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the azrul94 macro.
 
Upvote 0

Forum statistics

Threads
1,224,836
Messages
6,181,252
Members
453,028
Latest member
letswriteafairytale

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