How can I use custom properties in an Excel header or formula?

  • Thread starter Ed the IT Consultant
  • Start date
E

Ed the IT Consultant

I would like to use the values of custom Excel properties in the printed
header. If this isn't possible, can they be displayed in a cell using some
formula?
 
B

Bob Phillips

'-----------------------------------------------------------------
Function DocProps(prop As String)
'-----------------------------------------------------------------
Application.Volatile
On Error GoTo err_value
DocProps = ActiveWorkbook.BuiltinDocumentProperties _
(prop)
Exit Function
err_value:
DocProps = CVErr(xlErrValue)
End Function


and enter in a cell such as
=DocProps ("last author")
or
=DocProps ("last save time")
 
G

Gary''s Student

Put something like this in the workbook code area:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
v = ThisWorkbook.CustomDocumentProperties("lab1").Value
ActiveSheet.PageSetup.CenterHeader = v
End Sub

Replace "lab1" with the name of your custom property. Because it is
workbook code, it is very easy to install and use:

1. right-click the tiny Excel icon just to the left of File on the Menu Bar
2. select View Code - this brings up a VBE window
3. paste the stuff in and close the VBE window

If you save the workbook, the macro will be saved with it.

To remove the macro:

1. bring up the VBE windows as above
2. clear the code out
3. close the VBE window

To learn more about macros in general, see:

http://www.mvps.org/dmcritchie/excel/getstarted.htm

To learn more about Event Macros (workbook code), see:

http://www.mvps.org/dmcritchie/excel/event.htm
 
G

Gord Dibben

Change Bob's code to this for Custom Properties

Function CustProps(prop As String)
Application.Volatile
On Error GoTo err_value
CustProps = ActiveWorkbook.CustomDocumentProperties(prop)
Exit Function
err_value:
CustProps = CVErr(xlErrValue)
End Function

=custprops("Checked By")

=custprops("Client")

To get a list of all Custom Properties run the following macro.

Sub customprops()
rw = 1
Worksheets.Add
For Each p In ActiveWorkbook.CustomDocumentProperties
Cells(rw, 1).Value = p.Name
Cells(rw, 4).Value = p.Value
rw = rw + 1
Next
End Sub


Gord Dibben MS Excel MVP
 
B

Bob Phillips

or better yet, combine them

'-----------------------------------------------------------------
Function DocProps(prop As String)
'-----------------------------------------------------------------
Application.Volatile
On Error GoTo not_builtin
DocProps = ActiveWorkbook.BuiltinDocumentProperties _
(prop)
Exit Function

not_builtin:
On Error GoTo err_value
DocProps = ActiveWorkbook.CustomDocumentProperties(prop)
Exit Function

err_value:
DocProps = CVErr(xlErrValue)
End Function
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top