Am I understanding you right that you want to have column G as first column, column F as second column, column E as third column and so on?
If that is indeed what you have in mind, this should do that.
Obviously, change references as required.
Sub Try_So()
Dim myArr, sh1 As Worksheet, sh2 As Worksheet, i As Long, x As Long
Set sh1 = Worksheets("Sheet1")
Set sh2 = Worksheets("Sheet2")
x = 1
myArr = sh1.Range("A1:G" & sh1.Cells(Rows.Count, 1).End(xlUp).Row).Value
For i = UBound(myArr, 2) To LBound(myArr, 2) Step -1
sh2.Cells(1, x).Resize(UBound(myArr)) = Application.Index(myArr, , i)
x = x + 1
Next i
End Sub
Or if you don't like the "x" variable, this should work also.
Sub Try_So_2()
Dim myArr, sh1 As Worksheet, sh2 As Worksheet, i As Long
Set sh1 = Worksheets("Sheet1")
Set sh2 = Worksheets("Sheet2")
myArr = sh1.Range("A1:G" & sh1.Cells(Rows.Count, 1).End(xlUp).Row).Value
For i = LBound(myArr, 2) To UBound(myArr, 2)
sh2.Cells(1, i).Resize(UBound(myArr)) = Application.Index(myArr, , UBound(myArr, 2) + 1 - i)
Next i
End Sub