Microsoft Office Forums

Go Back   Microsoft Office Forums > >

Reply
 
Thread Tools Display Modes
  #1  
Old 11-14-2012, 08:54 AM
rollie rollie is offline Prices from decimals to ticks Windows XP Prices from decimals to ticks Office 2007
Novice
Prices from decimals to ticks
 
Join Date: Nov 2012
Posts: 1
rollie is on a distinguished road
Default Prices from decimals to ticks


I'm looking for a formula to change bond prices from decimals to ticks. A tick is 1/32 of a point, so 99.50 would be 99-16. Additionally, after the number of ticks is listed, the following number should be in 1/8s of 1/32. So 99.5078 would be 99-162 (99 and 16/32s and 2/8's of a 32nd.)

I currently have the following formula, but it does not return the correct value in every situation.
=SUBSTITUTE(TRUNC(DOLLARFR(B1,32),2),".","-")&HLOOKUP(((B1-INT(B1))*32)-INT((B1-INT(B1))*32),{0,0.125,0.25,0.375,0.5,0.625,0.75,0. 875,1;"","1","2","3","+","5","6","7",""},2,TRUE)

i.e. for 109.0078 this returns 1092 when it should be 109-002....and for 108.9375 it returns 108-3 when it should be 108-30.

any help is greatly appreciated!!
Attached Files
File Type: xlsx pricetickshelp.xlsx (8.8 KB, 10 views)
Reply With Quote
  #2  
Old 11-17-2012, 08:08 PM
macropod's Avatar
macropod macropod is offline Prices from decimals to ticks Windows 7 64bit Prices from decimals to ticks Office 2010 32bit
Administrator
 
Join Date: Dec 2010
Location: Canberra, Australia
Posts: 21,963
macropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond repute
Default

Hi Rollie,

Try:
=INT(B1)&"-"&TEXT(INT(MOD(B1,1)*32),"00")&TEXT(ROUND(MOD(B1*3 2,1)*8,0),"0")

If you want to suppress the final '0' (eg 180-30 instead of 108-300), try:
=INT(B1)&"-"&TEXT(INT(MOD(B1,1)*32),"00")&TEXT(ROUND(MOD(B1*3 2,1)*8,0),"#")
__________________
Cheers,
Paul Edstein
[Fmr MS MVP - Word]
Reply With Quote
Reply



Similar Threads
Thread Thread Starter Forum Replies Last Post
Charting Help - Stock Prices Ligerdub PowerPoint 0 01-03-2012 04:59 AM

Other Forums: Access Forums

All times are GMT -7. The time now is 12:43 AM.


Powered by vBulletin® Version 3.8.11
Copyright ©2000 - 2024, vBulletin Solutions Inc.
Search Engine Optimisation provided by DragonByte SEO (Lite) - vBulletin Mods & Addons Copyright © 2024 DragonByte Technologies Ltd.
MSOfficeForums.com is not affiliated with Microsoft