Copy Data

kamranyd

Board Regular
Joined
Apr 24, 2018
Messages
142
Office Version
  1. 2021
Platform
  1. Windows
Hi, these code copy data from sheet "database" to sheet "quot" in cell 20 onwards but i want data should be copy to cell 20 till cell 49 or any limit i set.

VBA Code:
Option Explicit
Sub search_quote()
   Dim Fnd As Range
   Dim Ws1 As Worksheet
   Dim Ws2 As Worksheet
   Dim i As Long, j As Long
   
   Sheets("Quot").Unprotect
   Application.ScreenUpdating = False
   
   Set Ws1 = Sheets("database")
   Set Ws2 = Sheets("QUOT")
   Set Fnd = Ws1.Range("A:A").Find(Ws2.Range("B10").Value, , , xlWhole, , , , , False)
   If Fnd Is Nothing Then MsgBox "Quotation not found", vbExclamation, "Quote Search": Exit Sub
   
   Ws2.Range("E10").Value = Fnd.Offset(, 1).Value
   Ws2.Range("B13").Value = Fnd.Offset(, 2).Value
   Ws2.Range("B15").Value = Fnd.Offset(, 3).Value
   Ws2.Range("C64").Value = Fnd.Offset(, 7).Value
   Ws2.Range("A53").Value = Fnd.Offset(, 128).Value
   Ws2.Range("A54").Value = Fnd.Offset(, 129).Value
   
    j = 20
   For i = 1 To Ws1.Cells(Fnd.Row, Columns.Count).End(xlToLeft).Column Step 4
      Ws2.Range("A" & j).Value = Ws1.Cells(Fnd.Row, i + 8)
      Ws2.Range("B" & j).Value = Ws1.Cells(Fnd.Row, i + 9)
      Ws2.Range("C" & j).Value = Ws1.Cells(Fnd.Row, i + 10)
      Ws2.Range("D" & j).Value = Ws1.Cells(Fnd.Row, i + 11)
      j = j + 1
      Next i
    'Range("A20").Select
    'ActiveWindow.ScrollRow = 1
'Sheets("Quot").Protect AllowFormattingCells:=True
End Sub
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
so i came up with this way, its long but work. can anybody help to make these codes short, so it can execute fast.

VBA Code:
Sub search_quote()
   Dim Fnd As Range
   Dim Ws1 As Worksheet
   Dim Ws2 As Worksheet
   Dim i As Long, j As Long
   
   Sheets("Quot").Unprotect
   Application.ScreenUpdating = False
   
   Set Ws1 = Sheets("database")
   Set Ws2 = Sheets("QUOT")
   
   Set Fnd = Ws1.Range("A:A").Find(Ws2.Range("B10").Value, , , xlWhole, , , , , False)
   If Fnd Is Nothing Then MsgBox "Quotation not found", vbExclamation, "Quote Search": Exit Sub
   
   Ws2.Range("E10").Value = Fnd.Offset(, 1).Value
   Ws2.Range("B13").Value = Fnd.Offset(, 2).Value
   Ws2.Range("B15").Value = Fnd.Offset(, 3).Value
   Ws2.Range("C64").Value = Fnd.Offset(, 7).Value
   Ws2.Range("A20").Value = Fnd.Offset(, 8).Value
   Ws2.Range("B20").Value = Fnd.Offset(, 9).Value
   Ws2.Range("C20").Value = Fnd.Offset(, 10).Value
   Ws2.Range("D20").Value = Fnd.Offset(, 11).Value
   Ws2.Range("A21").Value = Fnd.Offset(, 12).Value
   Ws2.Range("B21").Value = Fnd.Offset(, 13).Value
   Ws2.Range("C21").Value = Fnd.Offset(, 14).Value
   Ws2.Range("D21").Value = Fnd.Offset(, 15).Value
   Ws2.Range("A22").Value = Fnd.Offset(, 16).Value
   Ws2.Range("B22").Value = Fnd.Offset(, 17).Value
   Ws2.Range("C22").Value = Fnd.Offset(, 18).Value
   Ws2.Range("D22").Value = Fnd.Offset(, 19).Value
   Ws2.Range("A23").Value = Fnd.Offset(, 20).Value
   Ws2.Range("B23").Value = Fnd.Offset(, 21).Value
   Ws2.Range("C23").Value = Fnd.Offset(, 22).Value
   Ws2.Range("D23").Value = Fnd.Offset(, 23).Value
   Ws2.Range("A24").Value = Fnd.Offset(, 24).Value
   Ws2.Range("B24").Value = Fnd.Offset(, 25).Value
   Ws2.Range("C24").Value = Fnd.Offset(, 26).Value
   Ws2.Range("D24").Value = Fnd.Offset(, 27).Value
   Ws2.Range("A25").Value = Fnd.Offset(, 28).Value
   Ws2.Range("B25").Value = Fnd.Offset(, 29).Value
   Ws2.Range("C25").Value = Fnd.Offset(, 30).Value
   Ws2.Range("D25").Value = Fnd.Offset(, 31).Value
   Ws2.Range("A26").Value = Fnd.Offset(, 32).Value
   Ws2.Range("B26").Value = Fnd.Offset(, 33).Value
   Ws2.Range("C26").Value = Fnd.Offset(, 34).Value
   Ws2.Range("D26").Value = Fnd.Offset(, 35).Value
   Ws2.Range("A27").Value = Fnd.Offset(, 36).Value
   Ws2.Range("B27").Value = Fnd.Offset(, 37).Value
   Ws2.Range("C27").Value = Fnd.Offset(, 38).Value
   Ws2.Range("D27").Value = Fnd.Offset(, 39).Value
   Ws2.Range("A28").Value = Fnd.Offset(, 40).Value
   Ws2.Range("B28").Value = Fnd.Offset(, 41).Value
   Ws2.Range("C28").Value = Fnd.Offset(, 42).Value
   Ws2.Range("D28").Value = Fnd.Offset(, 43).Value
   Ws2.Range("A29").Value = Fnd.Offset(, 44).Value
   Ws2.Range("B29").Value = Fnd.Offset(, 45).Value
   Ws2.Range("C29").Value = Fnd.Offset(, 46).Value
   Ws2.Range("D29").Value = Fnd.Offset(, 47).Value
   Ws2.Range("A30").Value = Fnd.Offset(, 48).Value
   Ws2.Range("B30").Value = Fnd.Offset(, 49).Value
   Ws2.Range("C30").Value = Fnd.Offset(, 50).Value
   Ws2.Range("D30").Value = Fnd.Offset(, 51).Value
   Ws2.Range("A31").Value = Fnd.Offset(, 52).Value
   Ws2.Range("B31").Value = Fnd.Offset(, 53).Value
   Ws2.Range("C31").Value = Fnd.Offset(, 54).Value
   Ws2.Range("D31").Value = Fnd.Offset(, 55).Value
   Ws2.Range("A32").Value = Fnd.Offset(, 56).Value
   Ws2.Range("B32").Value = Fnd.Offset(, 57).Value
   Ws2.Range("C32").Value = Fnd.Offset(, 58).Value
   Ws2.Range("D32").Value = Fnd.Offset(, 59).Value
   Ws2.Range("A33").Value = Fnd.Offset(, 60).Value
   Ws2.Range("B33").Value = Fnd.Offset(, 61).Value
   Ws2.Range("C33").Value = Fnd.Offset(, 62).Value
   Ws2.Range("D33").Value = Fnd.Offset(, 63).Value
   Ws2.Range("A34").Value = Fnd.Offset(, 64).Value
   Ws2.Range("B34").Value = Fnd.Offset(, 65).Value
   Ws2.Range("C34").Value = Fnd.Offset(, 66).Value
   Ws2.Range("D34").Value = Fnd.Offset(, 67).Value
   Ws2.Range("A35").Value = Fnd.Offset(, 68).Value
   Ws2.Range("B35").Value = Fnd.Offset(, 69).Value
   Ws2.Range("C35").Value = Fnd.Offset(, 70).Value
   Ws2.Range("D35").Value = Fnd.Offset(, 71).Value
   Ws2.Range("A36").Value = Fnd.Offset(, 72).Value
   Ws2.Range("B36").Value = Fnd.Offset(, 73).Value
   Ws2.Range("C36").Value = Fnd.Offset(, 74).Value
   Ws2.Range("D36").Value = Fnd.Offset(, 75).Value
   Ws2.Range("A37").Value = Fnd.Offset(, 76).Value
   Ws2.Range("B37").Value = Fnd.Offset(, 77).Value
   Ws2.Range("C37").Value = Fnd.Offset(, 78).Value
   Ws2.Range("D37").Value = Fnd.Offset(, 79).Value
   Ws2.Range("A38").Value = Fnd.Offset(, 80).Value
   Ws2.Range("B38").Value = Fnd.Offset(, 81).Value
   Ws2.Range("C38").Value = Fnd.Offset(, 82).Value
   Ws2.Range("D38").Value = Fnd.Offset(, 83).Value
   Ws2.Range("A39").Value = Fnd.Offset(, 84).Value
   Ws2.Range("B39").Value = Fnd.Offset(, 85).Value
   Ws2.Range("C39").Value = Fnd.Offset(, 86).Value
   Ws2.Range("D39").Value = Fnd.Offset(, 87).Value
   Ws2.Range("A40").Value = Fnd.Offset(, 88).Value
   Ws2.Range("B40").Value = Fnd.Offset(, 89).Value
   Ws2.Range("C40").Value = Fnd.Offset(, 90).Value
   Ws2.Range("D40").Value = Fnd.Offset(, 91).Value
   Ws2.Range("A41").Value = Fnd.Offset(, 92).Value
   Ws2.Range("B41").Value = Fnd.Offset(, 93).Value
   Ws2.Range("C41").Value = Fnd.Offset(, 94).Value
   Ws2.Range("D41").Value = Fnd.Offset(, 95).Value
   Ws2.Range("A42").Value = Fnd.Offset(, 96).Value
   Ws2.Range("B42").Value = Fnd.Offset(, 97).Value
   Ws2.Range("C42").Value = Fnd.Offset(, 98).Value
   Ws2.Range("D42").Value = Fnd.Offset(, 99).Value
   Ws2.Range("A43").Value = Fnd.Offset(, 100).Value
   Ws2.Range("B43").Value = Fnd.Offset(, 101).Value
   Ws2.Range("C43").Value = Fnd.Offset(, 102).Value
   Ws2.Range("D43").Value = Fnd.Offset(, 103).Value
   Ws2.Range("A44").Value = Fnd.Offset(, 104).Value
   Ws2.Range("B44").Value = Fnd.Offset(, 105).Value
   Ws2.Range("C44").Value = Fnd.Offset(, 106).Value
   Ws2.Range("D44").Value = Fnd.Offset(, 107).Value
   Ws2.Range("A45").Value = Fnd.Offset(, 108).Value
   Ws2.Range("B45").Value = Fnd.Offset(, 109).Value
   Ws2.Range("C45").Value = Fnd.Offset(, 110).Value
   Ws2.Range("D45").Value = Fnd.Offset(, 111).Value
   Ws2.Range("A46").Value = Fnd.Offset(, 112).Value
   Ws2.Range("B46").Value = Fnd.Offset(, 113).Value
   Ws2.Range("C46").Value = Fnd.Offset(, 114).Value
   Ws2.Range("D46").Value = Fnd.Offset(, 115).Value
   Ws2.Range("A47").Value = Fnd.Offset(, 116).Value
   Ws2.Range("B47").Value = Fnd.Offset(, 117).Value
   Ws2.Range("C47").Value = Fnd.Offset(, 118).Value
   Ws2.Range("D47").Value = Fnd.Offset(, 119).Value
   Ws2.Range("A48").Value = Fnd.Offset(, 120).Value
   Ws2.Range("B48").Value = Fnd.Offset(, 121).Value
   Ws2.Range("C48").Value = Fnd.Offset(, 122).Value
   Ws2.Range("D48").Value = Fnd.Offset(, 123).Value
   Ws2.Range("A49").Value = Fnd.Offset(, 124).Value
   Ws2.Range("B49").Value = Fnd.Offset(, 125).Value
   Ws2.Range("C49").Value = Fnd.Offset(, 126).Value
   Ws2.Range("D49").Value = Fnd.Offset(, 127).Value
   
   Ws2.Range("A51").Value = Fnd.Offset(, 128).Value
   Ws2.Range("A54").Value = Fnd.Offset(, 129).Value

    'Range("A20").Select
    'ActiveWindow.ScrollRow = 1
'Sheets("Quot").Protect AllowFormattingCells:=True
End Sub
 
Upvote 0
See if this improves the speed:
VBA Code:
Sub search_quote()
    Dim Fnd As Range, Ws1 As Worksheet, Ws2 As Worksheet, x As Long, y As Long: y = 20
    Sheets("Quot").Unprotect
    Application.ScreenUpdating = False
    Set Ws1 = Sheets("database")
    Set Ws2 = Sheets("QUOT")
    Set Fnd = Ws1.Range("A:A").Find(Ws2.Range("B10").Value, , , xlWhole, , , , , False)
    If Fnd Is Nothing Then MsgBox "Quotation not found", vbExclamation, "Quote Search": Exit Sub
    With Ws2
        .Range("E10").Value = Fnd.Offset(, 1).Value
        .Range("B13").Value = Fnd.Offset(, 2).Value
        .Range("B15").Value = Fnd.Offset(, 3).Value
        .Range("C64").Value = Fnd.Offset(, 7).Value
        .Range("A51").Value = Fnd.Offset(, 128).Value
        .Range("A54").Value = Fnd.Offset(, 129).Value
        For x = 8 To 127 Step 4
            .Range("A" & y).Resize(, 4).Value = Array(Fnd.Offset(, x).Value, Fnd.Offset(, x + 1).Value, Fnd.Offset(, x + 2).Value, Fnd.Offset(, x + 3).Value)
            y = y + 1
        Next x
    End With
     'Range("A20").Select
     'ActiveWindow.ScrollRow = 1
    'Sheets("Quot").Protect AllowFormattingCells:=True
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
hi, here I did some changes only the problem is it copy data to sheet "inv" column A , b & c are merge cell but it copy data, than d, but it doesn't copy data on sheet "inv" column e. which is unit price. first 3 columsn getting copy but not the 4th column, may due to merge cell. any help

VBA Code:
Sub search_inv()
    Dim Fnd As Range, Ws1 As Worksheet, Ws2 As Worksheet, x As Long, y As Long: y = 21
    Sheets("inv").Unprotect
    Application.ScreenUpdating = False
    Set Ws1 = Sheets("invdatabase")
    Set Ws2 = Sheets("inv")
    Set Fnd = Ws1.Range("G:G").Find(Ws2.Range("F10").Value, , , xlWhole, , , , , False)
    If Fnd Is Nothing Then MsgBox "Invoice not found", vbExclamation, "Invoice Search": Exit Sub
    With Ws2
        
         .Range("F11").Value = Fnd.Offset(, 1).Value
         .Range("B10").Value = Fnd.Offset(, 0 - 6).Value
         .Range("B11").Value = Fnd.Offset(, 0 - 5).Value
         .Range("B12").Value = Fnd.Offset(, 0 - 4).Value
         .Range("B13").Value = Fnd.Offset(, 0 - 3).Value
         .Range("B14").Value = Fnd.Offset(, 0 - 2).Value
         .Range("B15").Value = Fnd.Offset(, 0 - 1).Value
         .Range("B17").Value = Fnd.Offset(, 2).Value
         .Range("D65").Value = Fnd.Offset(, 6).Value

        
         For x = 7 To 130 Step 4
            .Range("A" & y).Resize(, 4).Value = Array(Fnd.Offset(, x).Value, Fnd.Offset(, x + 1).Value, Fnd.Offset(, x + 2).Value, Fnd.Offset(, x + 3).Value)
            y = y + 1
        Next x
    End With
     'Range("A21").Select
     'ActiveWindow.ScrollRow = 1
     'Sheets("inv").Protect AllowFormattingCells:=True
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
It would be easier to help if you could use the XL2BB add-in (icon in the menu) to attach a screenshot (not a picture) of both sheets. Alternately, you could upload a copy of your file to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. Explain in detail what you want to do referring to specific cells, rows, columns and sheets using a few examples from your data (de-sensitized if necessary).
 
Upvote 0

Forum statistics

Threads
1,214,652
Messages
6,120,746
Members
448,989
Latest member
mariah3

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