Too long macro. Need to shorten it

Temporary-Failure

Board Regular
Joined
Jul 16, 2010
Messages
140
I have stupid macro :LOL: It's too long. How to shorten it? Use some kind of loop?

Code:
Sub Makro7()

    Range("B22:F22").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-21]C[13]="""","""",Tilaustiedot!R[-21]C[13])"
    Range("B23:F23").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-19]C[13]="""","""",Tilaustiedot!R[-19]C[13])"
    Range("B24:F24").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-17]C[13]="""","""",Tilaustiedot!R[-17]C[13])"
    Range("B25:F25").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-15]C[13]="""","""",Tilaustiedot!R[-15]C[13])"
    Range("B26:F26").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-13]C[13]="""","""",Tilaustiedot!R[-13]C[13])"
    Range("B27:F27").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-11]C[13]="""","""",Tilaustiedot!R[-11]C[13])"
    Range("B28:F28").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-9]C[13]="""","""",Tilaustiedot!R[-9]C[13])"
    Range("B29:F29").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-7]C[13]="""","""",Tilaustiedot!R[-7]C[13])"
    Range("B30:F30").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-5]C[13]="""","""",Tilaustiedot!R[-5]C[13])"
    Range("B31:F31").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-3]C[13]="""","""",Tilaustiedot!R[-3]C[13])"
    Range("B32:F32").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-1]C[13]="""","""",Tilaustiedot!R[-1]C[13])"
    Range("B33:F33").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+1]C[13]="""","""",Tilaustiedot!R[+1]C[13])"
    Range("B34:F34").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+3]C[13]="""","""",Tilaustiedot!R[+3]C[13])"
    Range("B35:F35").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+5]C[13]="""","""",Tilaustiedot!R[+5]C[13])"
    Range("B36:F36").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+7]C[13]="""","""",Tilaustiedot!R[+7]C[13])"
    Range("B37:F37").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+9]C[13]="""","""",Tilaustiedot!R[+9]C[13])"
    Range("B38:F38").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+11]C[13]="""","""",Tilaustiedot!R[+11]C[13])"
    Range("B39:F39").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+13]C[13]="""","""",Tilaustiedot!R[+13]C[13])"
    Range("B40:F40").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+15]C[13]="""","""",Tilaustiedot!R[+15]C[13])"
    Range("B41:F41").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+17]C[13]="""","""",Tilaustiedot!R[+17]C[13])"
    Range("B42:F42").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+19]C[13]="""","""",Tilaustiedot!R[+19]C[13])"
    Range("B43:F43").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+21]C[13]="""","""",Tilaustiedot!R[+21]C[13])"
    Range("B44:F44").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+23]C[13]="""","""",Tilaustiedot!R[+23]C[13])"
    Range("B45:F45").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+25]C[13]="""","""",Tilaustiedot!R[+25]C[13])"
    Range("B46:F46").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+27]C[13]="""","""",Tilaustiedot!R[+27]C[13])"
    Range("B47:F47").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+29]C[13]="""","""",Tilaustiedot!R[+29]C[13])"
    Range("B48:F48").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+31]C[13]="""","""",Tilaustiedot!R[+31]C[13])"
    Range("A1").Select
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
Does this work?
Code:
Sub Makro7()
 
    Dim i As Integer, r As Integer
 
    r = -21
 
    For i = 22 To 48
        Range("B" & i & ":F" & i).FormulaR1C1 = "=IF(Tilaustiedot!R[" & r & "]C[13]="""","""",Tilaustiedot!R[" & r & "]C[13])"
        r = r + 2
    Next i
 
End Sub
 
Upvote 0
Craig's suggestion should work with one caveat. Your code selects B{n}:F{n} but the use of ActiveCell means the formula is entered only in B{n}. Craig's suggestion will enter the formula in each of the cells B{n}:F{n}.
I have stupid macro :LOL: It's too long. How to shorten it? Use some kind of loop?

Code:
Sub Makro7()

    Range("B22:F22").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-21]C[13]="""","""",Tilaustiedot!R[-21]C[13])"
    Range("B23:F23").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-19]C[13]="""","""",Tilaustiedot!R[-19]C[13])"
    Range("B24:F24").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-17]C[13]="""","""",Tilaustiedot!R[-17]C[13])"
    Range("B25:F25").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-15]C[13]="""","""",Tilaustiedot!R[-15]C[13])"
    Range("B26:F26").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-13]C[13]="""","""",Tilaustiedot!R[-13]C[13])"
    Range("B27:F27").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-11]C[13]="""","""",Tilaustiedot!R[-11]C[13])"
    Range("B28:F28").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-9]C[13]="""","""",Tilaustiedot!R[-9]C[13])"
    Range("B29:F29").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-7]C[13]="""","""",Tilaustiedot!R[-7]C[13])"
    Range("B30:F30").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-5]C[13]="""","""",Tilaustiedot!R[-5]C[13])"
    Range("B31:F31").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-3]C[13]="""","""",Tilaustiedot!R[-3]C[13])"
    Range("B32:F32").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[-1]C[13]="""","""",Tilaustiedot!R[-1]C[13])"
    Range("B33:F33").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+1]C[13]="""","""",Tilaustiedot!R[+1]C[13])"
    Range("B34:F34").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+3]C[13]="""","""",Tilaustiedot!R[+3]C[13])"
    Range("B35:F35").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+5]C[13]="""","""",Tilaustiedot!R[+5]C[13])"
    Range("B36:F36").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+7]C[13]="""","""",Tilaustiedot!R[+7]C[13])"
    Range("B37:F37").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+9]C[13]="""","""",Tilaustiedot!R[+9]C[13])"
    Range("B38:F38").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+11]C[13]="""","""",Tilaustiedot!R[+11]C[13])"
    Range("B39:F39").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+13]C[13]="""","""",Tilaustiedot!R[+13]C[13])"
    Range("B40:F40").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+15]C[13]="""","""",Tilaustiedot!R[+15]C[13])"
    Range("B41:F41").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+17]C[13]="""","""",Tilaustiedot!R[+17]C[13])"
    Range("B42:F42").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+19]C[13]="""","""",Tilaustiedot!R[+19]C[13])"
    Range("B43:F43").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+21]C[13]="""","""",Tilaustiedot!R[+21]C[13])"
    Range("B44:F44").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+23]C[13]="""","""",Tilaustiedot!R[+23]C[13])"
    Range("B45:F45").Select

    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+25]C[13]="""","""",Tilaustiedot!R[+25]C[13])"
    Range("B46:F46").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+27]C[13]="""","""",Tilaustiedot!R[+27]C[13])"
    Range("B47:F47").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+29]C[13]="""","""",Tilaustiedot!R[+29]C[13])"
    Range("B48:F48").Select
    
    ActiveCell.FormulaR1C1 = _
        "=IF(Tilaustiedot!R[+31]C[13]="""","""",Tilaustiedot!R[+31]C[13])"
    Range("A1").Select
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,561
Members
449,089
Latest member
Motoracer88

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