Delete first and last item for each cell in the same column for two sheets

abdo meghari

Well-known Member
Joined
Aug 3, 2021
Messages
573
Office Version
  1. 2019
Hi guys,
I would macro to delete the first and last item for each cell in column J for two sheets.
the first item always contains space after it and last item always contains space before it . also will contain many letters for first and last item.
CH.xlsm
IJKLMN
1CODEBRANDUNIT PRICE1UNIT PRICE2UNIT PRICE3UNIT PRICE4
21241BS 1200R20 G580 JAP2035000
31244BS 1200R20 R187 JAP2000000
41269BS 1200R24 G580 JAP1900000
51556BS 185R14C R660 TR423000
61221BS 205/70R15C R623 THI405000
71547BS 205R16C D840 THI625000
81502BS 215/65R16C R611 THI60058300
91227BS 215/70R15C R623 THI42554400
101503BS 225/85R16C R202 JAP975000
111310BS 225/95R16C D618 JAP515695715700
121402BS 245/70R16 D697 JAP590000
131346DUN 255/70R15C D840 JAPAN50563500
141326BS 265/60R18 D840 JAP721000
151534BS 265/65R17 D693 THAILAND745000
161391BS 265/65R17 D840 JAP53569000
171411MARS 275/55R20 ALENZA1 KORIA72594200
181190BS 285/50R20 DSPORT JAP93670500
191315BS 315/80R22.5 G580 JAP 2470000
201257BS 315/80R22.5 R184 JAP2015000
211401BS 650R16 R230 JAP570000
221305HILO 700R16 R230 JAP762000
231306BS 750R16 R230 JAP71594000
241307BS 750R16 VSJ JAP910000
251284GC 1200R20 AZ0026 CHINA895112500
261285GC 1200R20 AZ0183 CHI925122512050
271292GC 1200R24 AZ166 CHI935000
281385GC 315/80R22.5 AT161 CHI73595500
291287GC 315/80R22.5 AZ126 CHI735000
301294GC 315/80R22.5 AZ188 CHI74596500
311492GC 385/65R22.5 AT131 CHI1275000
321528TH 185/65R14 H-93 CHI134000
331493WL 195/65R15 Z-108 CHI173000
341486WL 205/55R16 Z-108 CHI185000
PURCHASING


CH.xlsm
IJKLM
1CODEBRANDQTYUNIT PRICETOTAL
21306BS 750R16 R230 JAP107757750
31306BS 750R16 R230 JAP47803120
41305BS 700R16 R230 JAP27701540
SELLING
Cell Formulas
RangeFormula
M2:M4M2=K2*L2




Result
CH.xlsm
IJKLMN
1CODEBRANDUNIT PRICE1UNIT PRICE2UNIT PRICE3UNIT PRICE4
212411200R20 G5802035000
312441200R20 R1872000000
412691200R24 G5801900000
51556185R14C R660423000
61221205/70R15C R623405000
71547205R16C D840625000
81502215/65R16C R61160058300
91227215/70R15C R62342554400
101503225/85R16C R202975000
111310225/95R16C D618515695715700
121402245/70R16 D697590000
131346255/70R15C D84050563500
141326265/60R18 D840721000
151534265/65R17 D693745000
161391265/65R17 D84053569000
171411275/55R20 ALENZA172594200
181190285/50R20 DSPORT93670500
191315315/80R22.5 G5802470000
201257315/80R22.5 R1842015000
211401650R16 R230570000
221305700R16 R230762000
231306750R16 R23071594000
241307750R16 VSJ910000
2512841200R20 AZ0026895112500
2612851200R20 AZ0183925122512050
2712921200R24 AZ166935000
281385315/80R22.5 AT16173595500
291287315/80R22.5 AZ126735000
301294315/80R22.5 AZ18874596500
311492385/65R22.5 AT1311275000
321528185/65R14 H-93134000
331493195/65R15 Z-108173000
341486205/55R16 Z-108185000
PURCHASING


the same thing for second sheet
thanks
 
Taking off the first and last "word" is not a big issue. (So there will be a variable number of parts remaining not always 2)
However, I need some way of determining if the code has already updated the Brand on that line.
What pattern can be relied on ? How is the code to tell if the first and last word have already been removed ?
 
Upvote 0

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
What pattern can be relied on ? How is the code to tell if the first and last word have already been removed ?
could run the code from just the first time without repeating running every time to avoid repeat delete first, last items, or you need two helpers columns contains specific items should delete it?
what's the right way to advice me?
 
Upvote 0
Here is a modification of the first version I gave you in post #3, which will remove the first and last word and handle any additional leading or trailing spaces.
If you run it a second time it won't update anything that only has 2 or 3 words remaining but if there are 4 or more then it will update.
So if the original has 5 parts it will reduce to 3 remaining and won't update on a 2nd pass.
If the original has 6 parts it will reduce to 4 and WILL be picked up by a 2nd pass and be cut down to 2.
Unless you want to add another column that flags the updated rows I don't see any other way to avoid that 2nd update.

Rich (BB code):
Sub ExtractProductCode_MixedMethod()

    Dim ws As Worksheet
    Dim shtNames As Variant
    Dim rngBrand As Range, arrBrand As Variant
    Dim sBrand As String, posStart As Long, posEnd As Long
    Dim splitBrand As Variant
    Dim LastRow As Long, i As Long, iSht As Long
           
    shtNames = Array("Purchasing", "Selling")                   ' Update to your sheet names
   
    For iSht = 0 To UBound(shtNames)
        Set ws = Worksheets(shtNames(iSht))
        With ws
            LastRow = .Range("J" & Rows.Count).End(xlUp).Row
            Set rngBrand = .Range(.Cells(2, "J"), .Cells(LastRow, "J"))
            arrBrand = rngBrand.Value
        End With
       
        For i = 1 To UBound(arrBrand)
            sBrand = Application.Trim(arrBrand(i, 1))
            splitBrand = Split(sBrand, " ")
            ' Check that there are at least 4 parts
            If UBound(splitBrand) >= 3 Then
                posStart = InStr(1, sBrand, " ") + 1
                posEnd = InStrRev(sBrand, " ") - 1
                arrBrand(i, 1) = Mid(sBrand, posStart, posEnd - posStart + 1)
            End If
        Next i
       
        rngBrand.Value = arrBrand
   
    Next iSht
End Sub
 
Upvote 0
ok this great !
but,
If the original has 6 parts it will reduce to 4 and WILL be picked up by a 2nd pass and be cut down to 2.
Unless you want to add another column that flags the updated rows I don't see any other way to avoid that 2nd update.
in this case could use helper column D for each sheet ?
I mean after run the code then will copy brands from column G to column D as helper then when run again the macro then will not update the brand in column G if they are existed in column D.
thanks again
 
Upvote 0
So far we have been reading and updating column J.
How does column G fit into the picture ?
After the update what will be in D and what will be in G/J ?
 
Upvote 0
I'm guessing from the sample data provided that the first part always starts with a letter and the second part always starts with a digit. IF that is the case then you could try this code which would not remove anything if it was run a second time.

VBA Code:
Sub Fix_Brand()
  Dim RX As Object, M As Object
  Dim a As Variant, aSheets As Variant, Sh As Variant
  Dim i As Long
  
  aSheets = Split("PURCHASING|SELLING", "|")
  Set RX = CreateObject("VBScript.RegExp")
  RX.Pattern = "(^[^0-9]+ )(.*?)( [^ ]+ ?$)"
  For Each Sh In aSheets
    With Sheets(Sh)
      With .Range("J2", .Range("J" & Rows.Count).End(xlUp))
        a = .Value
        For i = 1 To UBound(a)
          Set M = RX.Execute(a(i, 1))
          a(i, 1) = RX.Replace(a(i, 1), "$2")
        Next i
        .Value = a
      End With
    End With
  Next Sh
End Sub
 
Upvote 0
"After the update what will be in D and what will be in J ?"
then will just update when there is new brand in column J and is not existed in column D .
in this case after update for new brand in column J will copy to column D .
in other meaning if the the same brand is existed for two columns D,J then will not update .
 
Upvote 0
1) Please try Peter's code before we proceed
2) If Peter's code doesn't work for you please give an updated and representative sample of your data.
Currently the sample has 4 parts and Peter has used a pattern based on that. If that pattern does not hold true when you have more parts we need visibility of a realistic set of data.
3) If I update my code will D have the before or after Brand Name in it. (or we just flag it with a Y for updated)
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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