Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 10
Default Macro for absolute reference

Hello,

I have one excel book , which have 30 sheets (28 sheets are named as different
account manager's name),
1 sheet name as "summary" , last sheet name as "system data"

I would like to use macro to change relative reference to absolute reference
(only column absolute!!) on sheet"summary".
May I ask how to modify the following code to achieve absolute reference
:column). Thanks

Sub CycleAbsRel()
Dim inRange as Range, oneCell As Range
Static absRelMode As Long
absRelMode = (absRelMode Mod 4) + 1
Set inRange = Selection.SpecialCells(xlCellTypeFormulas)
If Not (inRange Is Nothing) Then
For Each oneCell In inRange
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)
End With
Next oneCell
End If
End Sub
  #2   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 621
Default Macro for absolute reference

Start with these...............

Sub Absolute()
Dim cell As Range
For Each cell In Selection
If cell.HasFormula Then
cell.Formula = Application.ConvertFormula _
(cell.Formula, xlA1, xlA1, xlAbsolute)
End If
Next
End Sub

Sub AbsoluteRow()
Dim cell As Range
For Each cell In Selection
If cell.HasFormula Then
cell.Formula = Application.ConvertFormula _
(cell.Formula, xlA1, xlA1, xlAbsRowRelColumn)
End If
Next
End Sub

Sub AbsoluteCol()
Dim cell As Range
For Each cell In Selection
If cell.HasFormula Then
cell.Formula = Application.ConvertFormula _
(cell.Formula, xlA1, xlA1, xlRelRowAbsColumn)
End If
Next
End Sub

Sub Relative()
Dim cell As Range
For Each cell In Selection
If cell.HasFormula Then
cell.Formula = Application.ConvertFormula _
(cell.Formula, xlA1, xlA1, xlRelative)
End If
Next
End Sub


Gord Dibben MS Excel MVP

On Sat, 07 May 2011 10:47:55 -0500, john-lau wrote:

Hello,

I have one excel book , which have 30 sheets (28 sheets are named as different
account manager's name),
1 sheet name as "summary" , last sheet name as "system data"

I would like to use macro to change relative reference to absolute reference
(only column absolute!!) on sheet"summary".
May I ask how to modify the following code to achieve absolute reference
:column). Thanks

Sub CycleAbsRel()
Dim inRange as Range, oneCell As Range
Static absRelMode As Long
absRelMode = (absRelMode Mod 4) + 1
Set inRange = Selection.SpecialCells(xlCellTypeFormulas)
If Not (inRange Is Nothing) Then
For Each oneCell In inRange
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)
End With
Next oneCell
End If
End Sub

  #3   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 10
Default Macro for absolute reference

john-lau wrote on 05/07/2011 11:47 ET :
Hello,

I have one excel book , which have 30 sheets (28 sheets are named as

different
account manager's name),
1 sheet name as "summary" , last sheet name as "system
data"

I would like to use macro to change relative reference to absolute reference
(only column absolute!!) on sheet"summary".
May I ask how to modify the following code to achieve absolute reference
:column). Thanks

Sub CycleAbsRel()
Dim inRange as Range, oneCell As Range
Static absRelMode As Long
absRelMode = (absRelMode Mod 4) + 1
Set inRange = Selection.SpecialCells(xlCellTypeFormulas)
If Not (inRange Is Nothing) Then
For Each oneCell In inRange
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)
End With
Next oneCell
End If
End Sub

Dear sir,

thanks for your reply. May you teach me how to modify the macro, therefore, I
can apply it for specific/current sheet of the file. For example, there is a
workbook called DB performance, it has 4 sheets, I only want macro (absolute
reference) applied on specific sheet, such as Premier..

Secondly, for example, in the sheet "premier", Column A, there are two
sources of data (from two sheets, one is "David" and "system
report".
The formula like this
in the sheet "premier" A 3 , the formula is "david" A1+
"system report" A1+"david" B1+ "system report" B1.
After I use the macro, it shows # Value..... Is it my formula has problems?
  #4   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 621
Default Macro for absolute reference

First...................revised macro.

Sub AbsoluteCol()
Dim wkbk As Workbook
Dim wksh As Worksheet
Set wkbk = Workbooks("DB Performance.xls")
Set wksh = wkbk.Sheets("Premier")
Dim cell As Range
For Each cell In wksh.UsedRange
If cell.HasFormula Then
cell.Formula = Application.ConvertFormula _
(cell.Formula, xlA1, xlA1, xlRelRowAbsColumn)
End If
Next
End Sub


Second...................your formula does not look like any kind of valid
formula.

Are you summing the cells by using the + sign?

Please copy and paste the actual formula you have in A3

I assumed summing and tested with this formula in A3

=SUM(david!A1:B1)+SUM('system report'!A1:B1)

Ran the macro and returned this in A3

=SUM(david!$A1:$B1)+SUM('system report'!$A1:$B1)

No problems.


Gord


On Sat, 07 May 2011 21:32:04 -0500, john-lau wrote:

john-lau wrote on 05/07/2011 11:47 ET :
Hello,

I have one excel book , which have 30 sheets (28 sheets are named as

different
account manager's name),
1 sheet name as "summary" , last sheet name as "system
data"

I would like to use macro to change relative reference to absolute reference
(only column absolute!!) on sheet"summary".
May I ask how to modify the following code to achieve absolute reference
:column). Thanks

Sub CycleAbsRel()
Dim inRange as Range, oneCell As Range
Static absRelMode As Long
absRelMode = (absRelMode Mod 4) + 1
Set inRange = Selection.SpecialCells(xlCellTypeFormulas)
If Not (inRange Is Nothing) Then
For Each oneCell In inRange
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)
End With
Next oneCell
End If
End Sub

Dear sir,

thanks for your reply. May you teach me how to modify the macro, therefore, I
can apply it for specific/current sheet of the file. For example, there is a
workbook called DB performance, it has 4 sheets, I only want macro (absolute
reference) applied on specific sheet, such as Premier..

Secondly, for example, in the sheet "premier", Column A, there are two
sources of data (from two sheets, one is "David" and "system
report".
The formula like this
in the sheet "premier" A 3 , the formula is "david" A1+
"system report" A1+"david" B1+ "system report" B1.
After I use the macro, it shows # Value..... Is it my formula has problems?

  #5   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 1
Default Macro for absolute reference

Hi Gord,

Would you explain to me the following piece of this code? I gather that it increments which rel/abs option is applied (right?). But i dont really understand the mechanics of how or why it does so.

"absRelMode = (absRelMode Mod 4) + 1"

Thanks,
Tyler



Sub CycleAbsRel()
Dim inRange as Range, oneCell As Range
Static absRelMode As Long
absRelMode = (absRelMode Mod 4) + 1
Set inRange = Selection.SpecialCells(xlCellTypeFormulas)
If Not (inRange Is Nothing) Then
For Each oneCell In inRange
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)
End With
Next oneCell
End If
End Sub




  #6   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 829
Default Macro for absolute reference

"Tyler" wrote:
Would you explain to me the following piece of this code?

[....]
"absRelMode = (absRelMode Mod 4) + 1"


It assigns the values 1, 2, 3 and 4 to absRelMode cyclically each time
CycleAbsRel is executed. Note that absRelMode is initially zero when VBA is
reset.

I do not have the context of the thread you are responding to.

However:
With oneCell
.FormulaR1C1 = Application.ConvertFormula(.FormulaR[1]C1, xlR1C1, xlR1C1,
absRelMode, oneCell)


First, I think there is a typo: the 1st parameter should be .FormulaR1C1.

Second, I'm not sure this will work in XL2007 and later.

According to offline help in XL2003, the 4th parameter is an
xlReferenceStyle type, which can take 4 values: xlAbsolute (1),
xlAbsRowRelColumn (2), xlRelRowAbsColumn (3) and xlRelative (4). Thus the
reason for absRelMode to take have the values 1 through 4.

(Arguably, it is not "good form" to assume those constant values for the
named constants. It would be "better form" to use absRelMode to index into
an array of the named constants.)

However, according to offline help in XL2007 and later, xlReferenceStyle is
defined to have only 2 values: xlA1 (1) and xlR1C1 (-4150).

(There you can see why we should not assume specific constant values for
named constants.)

I suspect the XL2007/later offline help documentation is incorrect, since
those named constants do not make sense for that parameter. But I am not
bothering to test it.

Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
absolute cell reference macro rk0909 Excel Discussion (Misc queries) 4 November 7th 09 12:37 AM
Absolute cell reference will not remain absolute. Mike K Excel Worksheet Functions 1 October 8th 08 07:12 PM
Recording Macro, toggle absolute/relative reference, button disapp Kayos Excel Programming 2 October 18th 05 08:42 PM
Macro problem. Need a vague not absolute reference Jeff Whitbey Excel Programming 4 July 20th 04 01:09 PM
Creating an Absolute Reference Macro Renegade Snail Excel Programming 5 March 1st 04 12:47 PM


All times are GMT +1. The time now is 09:49 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"