Trig function in macro

Westbury

Board Regular
Joined
Jun 7, 2009
Messages
139
In a spreadsheet I have 2 columns with latitude and longitude for many points; these would be Lat2 & Long2. I also have the Lat and Longitude for a fixed point; these will be Lat1 & Long1

I would like to use this equation in a macro

Excel Formula:
MOD(ATAN2(COS(RADIANS(lat1))*SIN(RADIANS(lat2))-SIN(RADIANS(lat1))*COS(RADIANS(lat2))*COS(RADIANS(long2-long1)),COS(RADIANS(lat2))*SIN(RADIANS(long2-long1)))*180/PI(),360

but I know that MOD & ATAN2 don't work in VBA.

Is it possible to use something like Worksheet.formula to insert this equation in a column next to the Lat2, Long2 values bearing in mind that the Lat2 & Long cell refs need to increment down the column?

Thanks
 
Last edited by a moderator:

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
Why not use Application.Atan2 and VBA's own Mod function?
 
Upvote 0
What do you mean that you "would like to use this equation in a macro"? Use it how? To put the formulas in the cells for you? To do an internal calculation within the macro itself? Something else?

Also, it looks like your "formula" is missing something at the end (what I see is ",360". Rather than correcting it, why don't you show us your actual formula for the first cell you have your formula in so that we can know what columns are being referred to within the formula.
 
Upvote 0
To get the formula for the code to use, go to the first cell where you will want the code to start populating. Manually enter the correct formula for that cell making sure to use absolute ($) reference for lat1 and long1. Then switch to R1C1 reference style (File Options R1C1 ...). Copy the complete formula you wrote that is displayed in R1C1 reference style to the clipboard.

Pseudo code to put the formula into the desired range:
Dim Rng as Range
Set Rng = the range you want the code to populate
Rng.formulaR1C1 = the formula you copied including the equal sign inside of quotes i.e., "=MOD(...)"

Once you're satisfied with the results switch back to A1 reference style.
 
Upvote 0
I've used

to place the equation in the spreadsheet..

VBA Code:
Range("K24").Formula = "=MOD(ATAN2(COS(RADIANS($H$2))*SIN(RADIANS($H6))-SIN(RADIANS($H$2))*COS(RADIANS($H6))*COS(RADIANS($I6-$I$2)),COS(RADIANS($H6))*SIN(RADIANS($I6-$I$2)))*180/PI(),360)"

and to copy down the sheet

VBA Code:
    .Range("k24").Copy Destination:=Range("K25:K" & LastRow)

It works for me!

Thanks for your responses.
 
Last edited by a moderator:
Upvote 0
You do not need to use the Copy method... you can put all the formulas into the cells directly. This should place all your formulas into their correct cells (assuming the LastRow variable has already been assigned a value)...
Excel Formula:
Range("K24:K" & LastRow).Formula = "=MOD(ATAN2(COS(RADIANS($H$2))*SIN(RADIANS($H6))-SIN(RADIANS($H$2))*COS(RADIANS($H6))*COS(RADIANS($I6-$I$2)),COS(RADIANS($H6))*SIN(RADIANS($I6-$I$2)))*180/PI(),360)"
 
Upvote 0
Solution

Forum statistics

Threads
1,214,641
Messages
6,120,685
Members
448,978
Latest member
rrauni

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