×
INTELLIGENT WORK FORUMS
FOR ENGINEERING PROFESSIONALS

Contact US

Log In

Come Join Us!

Are you an
Engineering professional?
Join Eng-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Eng-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Students Click Here

Keeping formulas in excel fields
2

Keeping formulas in excel fields

Keeping formulas in excel fields

(OP)
Hey Excel gods,

is there any way of entering a formula in an excel field, so that if a single entry is made it will override the formula, but if the field is then cleared that the original formula returns.  For example : if A1 hold the formula "@sum(F3:F9)" but the user will be able to override this with a value, say the user enters "5" in A1.  The next user might not like this and clear the "5".  Is it now possible for the field A1 to go back to its original formula of "@sum(F3:F9)"?

Thanks in advance.

Crash

RE: Keeping formulas in excel fields

What you are looking for is impossible, unless you use a function that opens a dialog box where the user can choose to input a value or to use the standard provided formula.

prex
motori@xcalcsREMOVE.com
http://www.xcalcs.com
Online tools for structural design

RE: Keeping formulas in excel fields

2
This can be done with VBA, if you are interested. Just use the Worksheet_Change event to monitor the target cell. Simply insert this code in the sheet's object module.

Option Explicit

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    If Target.AddressLocal = "$A$1" Then
        If Len(Target.Text) > 0 Then
            Exit Sub
        Else
            Target.Formula = "=SUM(F3:F9)"
        End If
    End If
End Sub

You can also add some additional checking to validate the contents of the cell (i.e. only allow numerical entries).

Hope this helps...

DimensionalSolutions@Core.com
While I welcome e-mail messages, please post all thread activity in these forums for the benefit of all members.

RE: Keeping formulas in excel fields

Or you could do it the ugly way in Excel

user enters a value or puts 0 in cell A1

then A2 is if(A1=0,some formula,A1)

nasty but quick





Cheers

Greg Locock

RE: Keeping formulas in excel fields

why wouldnt the user just use "undo"?

Best Regards

Morten

RE: Keeping formulas in excel fields

(OP)
Thank you dsi!!

your code has helped alot.  many thanks.  Just one more question.  it puts the formula result in the the field after the the field is changed to 0.  Is there a way of it doing that check when the sheet is made active?  I tried using the worksheet_activate event but I get compiling errors if I use that.

Thanks again

RE: Keeping formulas in excel fields

If you want to accept a value of zero, you can not use the contents check in the earlier example. That simply checks to make sure the cell is not empty. Here is an alternative:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    If Target.AddressLocal = "$A$1" Then
        If IsNumeric(Target.Text) = True Then
            If Target.Value = 0 Then Exit Sub
        ElseIf Len(Target.Text) > 0 Then
            Exit Sub
        Else
            Target.Formula = "=SUM(F3:F9)"
        End If
    End If
End Sub

As for processing the check upon activating the sheet, use the Worksheet.Activate event to call the Change event:

Private Sub Worksheet_Activate()
    Call Worksheet_Change(Range("A1"))
End Sub

Good luck...

DimensionalSolutions@Core.com
While I welcome e-mail messages, please post all thread activity in these forums for the benefit of all members.

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Eng-Tips Forums free from inappropriate posts.
The Eng-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Eng-Tips forums is a member-only feature.

Click Here to join Eng-Tips and talk with other members! Already a Member? Login


Resources

Low-Volume Rapid Injection Molding With 3D Printed Molds
Learn methods and guidelines for using stereolithography (SLA) 3D printed molds in the injection molding process to lower costs and lead time. Discover how this hybrid manufacturing process enables on-demand mold fabrication to quickly produce small batches of thermoplastic parts. Download Now
Design for Additive Manufacturing (DfAM)
Examine how the principles of DfAM upend many of the long-standing rules around manufacturability - allowing engineers and designers to place a part’s function at the center of their design considerations. Download Now
Taking Control of Engineering Documents
This ebook covers tips for creating and managing workflows, security best practices and protection of intellectual property, Cloud vs. on-premise software solutions, CAD file management, compliance, and more. Download Now

Close Box

Join Eng-Tips® Today!

Join your peers on the Internet's largest technical engineering professional community.
It's easy to join and it's free.

Here's Why Members Love Eng-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close