Hi David,
True.  The worksheet as posted had no formulas, but it is worth trying and
would likely be beneficial if the macro will be used on a sheet with
formulas.
The "fast" version of the function probably only has 4 lines of VBA that
could trigger calculation(one shifts the values with a range.value2
assignment, one clears a group of cells, the third inserts a group of rows,
and the fourth places text in a cell of each of the newly inserted rows),
which might mean that only 4 recalculations could be triggered (though I'm
not sure on that).
The simpler function takes action on each record/group of cells individually
in a loop, and would likely benefit greatly from disabling calculation if
there are formulas.
Cheers,
Asa


-----Original Message-----
From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
On Behalf Of David Grugeon
Sent: Saturday, October 20, 2012 5:00 PM
To: excel-macros@googlegroups.com
Subject: Re: $$Excel-Macros$$ Re: Request for support for a looping macro

I wonder if it would speed it up if you set calculation to xlmanual?


Regards
David Grugeon


On 21 October 2012 03:23, Asa Rossoff <a...@lovetour.info> wrote:
> Hi Diamond Dave,
>
> I started out planning to give you a few general thoughts just based on
your
> email, without having seen the workbook.  I typed out more than a few in
the
> end, and then thought, if that was worth the time, it's surely worth the
> time to find your old message, open your attachment and actually take a
> look.
>
>
>
> When I took a look, I found that none of my typed examples, although I
hoped
> would be generally educational, would get you all the way to a solution.
So
> I worked up a working rewrite of your routine for you.  I will list that
> first.
>
>
>
> This working version doesn't use A1 for the number of shifts to perform.
It
> calculates the same for display purposes (status bar), but in fact it
works
> its way down the sheet using the equivalent of Ctrl-DownArrow --
> RANGE.End(xlDown) -- and processes each dataset/record that it finds and
> that needs shifting (it won't shift ones that have already been shifted).
>
>
>
> See attached file or download the same: Fast Shifting of disparate
> ranges-for Diamond (asa).xls
>
> https://docs.google.com/open?id=0Bwkcc6g0MuPTUWZFQTE1RG1mZ1k
>
>
>
> Although this macro looks much different from yours, the effect is
> essentially the same. cut and paste each dataset:
>
> Sub asaShiftData()
>
> Dim Worksheet As Worksheet
>
> Dim DataSet As Range, TopLeft As Range
>
> Dim Rows As Long, Counter As Long, Counter2 As Long, Total As Long
>
> Dim Status As String
>
>     Set Worksheet = ThisWorkbook.Worksheets("Header")
>
>     Set TopLeft = Worksheet.Range("E1").End(xlDown).End(xlDown)
>
>     Application.ScreenUpdating = False
>
>     Total = WorksheetFunction.CountA(Worksheet.Range("B:B")) - 1
>
>     Do While TopLeft.Value <> ""
>
>         Counter2 = Counter2 + 1
>
>         If Counter2 Mod 10 = 0 Then DoEvents
>
>         Set DataSet = Worksheet.Range(TopLeft,
> TopLeft.End(xlToRight).End(xlDown))
>
>         If TopLeft.Offset(, -1).Value = "" Then
>
>             Counter = Counter + 1
>
>             DataSet.Cut Destination:=DataSet.Offset(, -1)
>
>             Rows = DataSet.Rows.Count
>
>             TopLeft.Offset(Rows).EntireRow.Insert
>
>             TopLeft.Offset(Rows).Value = "Variance"
>
>             Set TopLeft = TopLeft.Offset(, 1)
>
>         End If
>
>         Set TopLeft = TopLeft.End(xlDown).End(xlDown).End(xlDown)
>
>         GoSub GetStatus
>
>         Application.StatusBar = Status
>
>     Loop
>
>     Application.ScreenUpdating = True
>
>     Application.StatusBar = False
>
>     MsgBox Status
>
>     Exit Sub
>
> GetStatus:
>
>     Status = "Shifted " & Counter & " of " & Counter2 & "(" & Total & ")
> production lines.  " & Int(Counter2 / Total * 100) & "% complete."
>
> Return
>
> End Sub
>
>
>
> After testing the above macro with about 1,000 datasets to shift, I was
> concerned about the time it took: about 5.5 minutes.  So I worked up a
more
> efficient, but more complex version that did the same in 58 seconds.  It
has
> a few limitations, mentioned in comments in the code, but is suitable for
> most purposes:
>
> Sub asaShiftDataFast()
>
> Dim Worksheet As Worksheet
>
> Dim SourceRange As Range, InsertRange As Range, Cells As Range
>
> Dim DestinationRange As Range, DestCell1 As Range
>
> Dim SrcCol As Range, SrcCell As Range
>
> Dim TopLeft As Range, FirstColumn As Range
>
> Dim ColIdx As Long, ColLeftIdx As Long, ColRightIdx As Long
>
> Dim RowIdx As Long, RowCount As Long
>
> Dim Total As Long
>
> Dim SrcFont As Font, DestFont1 As Font
>
> Dim Abort As Boolean
>
>     Set Worksheet = ThisWorkbook.Worksheets("Header")
>
>     Set TopLeft = Worksheet.Range("E1").End(xlDown)
>
>     Set FirstColumn = TopLeft.EntireColumn
>
>     Total = WorksheetFunction.CountA(Worksheet.Range("B:B")) - 1
>
>
>
>     Application.ScreenUpdating = False
>
>
>
>     'Find rows that need shifting
>
>     'This approach is limited to 8,192 product lines
>
>     '  (areas in the range) in Excel versions < Excel 2010.
>
>     Application.StatusBar = "Identifying records that need shifting..."
>
>     On Error Resume Next ' specialcells generates error if no cells
>
>     Set SourceRange = FirstColumn.SpecialCells(xlCellTypeFormulas)
>
>     If SourceRange Is Nothing Then
>
>         Err.Clear
>
>         Set SourceRange = FirstColumn.SpecialCells(xlCellTypeConstants)
>
>     Else
>
>         Set SourceRange = Union(SourceRange,
> FirstColumn.SpecialCells(xlCellTypeConstants))
>
>     End If
>
>     Set SourceRange = SourceRange.Offset(,
> -1).SpecialCells(xlCellTypeBlanks)
>
>     Abort = Err.Number <> 0 'nothing to shift...
>
>     If Not Abort Then
>
>         Set SourceRange = SourceRange.Offset(,
> -2).SpecialCells(xlCellTypeBlanks)
>
>         Abort = Err.Number <> 0 'nothing to shift...
>
>         On Error GoTo 0 ' stop ignoring errors
>
>         If Not Abort Then
>
>             Set SourceRange = Intersect(SourceRange.EntireRow,
> Worksheet.Range(TopLeft, TopLeft.End(xlToRight)).EntireColumn)
>
>
>
>             'Check for formulas that will be lost.
>
>             On Error Resume Next
>
>             SourceRange.SpecialCells xlCellTypeFormulas 'discard result
>
>             If Err.Number = 0 Then
>
>                 Abort = MsgBox( _
>
>                           "Warning - some cells contain formulas that will
> be converted to values when shifted." & vbCrLf & vbCrLf & "Continue?", _
>
>                           vbQuestion + vbYesNo + vbDefaultButton2, _
>
>                           "ShiftData - Warning" _
>
>                         ) = vbNo
>
>             End If
>
>         Else
>
>             MsgBox "Nothing to do."
>
>         End If
>
>     Else
>
>         MsgBox "Nothing to do."
>
>     End If
>
>     On Error GoTo 0
>
>
>
>     If Not Abort Then
>
>         'Perform Shift (note:cut/paste won't work with many areas - but
this
> will)
>
>         Application.StatusBar = "Shifting data..."
>
>         Set DestinationRange = SourceRange.Offset(, -1)
>
>         DestinationRange.Value2 = SourceRange.Value2
>
>
>
>         'Transfer some basic formatting
>
>         '  Unlike cell values, we can't transfer the formatting
>
>         '  en bloc, so we assume each area is formatted alike
>
>         '  to save time.  The strategy used here assumes each
>
>         '  area is the same shape and size.
>
>         Application.StatusBar = "Formatting data..."
>
>         With DestinationRange.Areas(1).Columns
>
>             ColLeftIdx = .Item(1).Column
>
>             ColRightIdx = .Item(.Count).Column
>
>         End With
>
>         For ColIdx = ColLeftIdx To ColRightIdx
>
>             DoEvents
>
>             With Intersect(Worksheet.Columns(ColIdx), DestinationRange)
>
>                 Set SrcCol = .Offset(, 1)
>
>                 RowCount = .Areas(1).Rows.Count
>
>                 For RowIdx = 1 To RowCount
>
>                     With Intersect(.Offset(RowCount - 1),
> .Rows).Offset(RowIdx - RowCount)
>
>                         Set SrcCell = .Cells(1, 2)
>
>                         Set DestCell1 = .Cells(1)
>
>                         If DestCell1.NumberFormat <> SrcCell.NumberFormat
> Then .NumberFormat = SrcCell.NumberFormat
>
>                         Set SrcFont = SrcCell.Font
>
>                         Set DestFont1 = DestCell1.Font
>
>                         With .Font
>
>                             If DestFont1.Name <> SrcFont.Name Then .Name =
> SrcFont.Name
>
>                             If DestFont1.FontStyle <> SrcFont.FontStyle
Then
> .FontStyle = SrcFont.FontStyle
>
>                             If DestFont1.Size <> SrcFont.Size Then .Size =
> SrcFont.Size
>
>                             If DestFont1.Color <> SrcFont.Color Then
.Color
> = SrcFont.Color
>
>                        End With
>
>                     End With
>
>                 Next RowIdx
>
>             End With
>
>         Next ColIdx
>
>         Application.StatusBar = False
>
>
>
>         'Clear column to the right of DestinationRange
>
>         '  SrcCol is set to the rightmost destination column at end of
above
> loop.
>
>         SrcCol.Offset(, 1).Clear
>
>
>
>         'Find row below each area
>
>         DoEvents
>
>         Set InsertRange =
SourceRange.Offset(SourceRange.Areas(1).Rows.Count
> - 1)
>
>         Set InsertRange = Intersect(InsertRange, SourceRange).Offset(1)
>
>
>
>         'Insert rows (this is the most time consuming part)
>
>         Application.StatusBar = "Inserting rows..."
>
>         DoEvents
>
>         InsertRange.EntireRow.Insert
>
>
>
>         'Find first cells below shifted range and put new value in them.
>
>         Application.StatusBar = "Adding new label..."
>
>         DoEvents
>
>         Set Cells = Intersect(InsertRange,
> InsertRange.Columns(1).EntireColumn).Offset(-1, -1)
>
>         Cells.Value2 = "Variance"
>
>     End If
>
>     Application.StatusBar = False
>
>     Application.ScreenUpdating = True
>
>     If Not Abort Then MsgBox "Shifted " & Cells.Cells.Count & " of " &
Total
> & " production lines."
>
> End Sub
>
>
>
>
>
> Below are my original comments before looking at your file.  The code is
> untested.
>
>
>
> ###################################################
>
> Its true that your code is more complex than necessary.  I will try to
give
> you a few thoughts.
>
>
>
> LOOPING
>
> The simple answer to your question is you write a basic For/Next loop like
> this:
>
>
>
> Dim DataSetNumber As Long ' Put variable declarations at top of procedure
>
> For DataSetNumber = 1 to 1000
>
>     ' put stuff here to repeat
>
> Next DataSetNumber
>
>
>
> CELL VALUES
>
> You can extend this to using the value in A1.  Using your current code
> style, like this:
>
>
>
> Dim DataSetNumber As Long
>
> Dim DataSetCount As Long
>
> DataSetCount = Range("A1").Value
>
> For DataSetNumber = 1 to DataSetCount
>
>     ' put stuff here to repeat
>
> Next DataSetNumber
>
>
>
> EFFICIENCY - OVERVIEW
>
> For a macro to be quick, efficient, succint, and simple, you should
usually
> seek to avoid a few things I see in your code: selecting ranges,
> copying/cutting and pasting, references to the active cell (unless
logically
> required and the cell active before running the macro).  If the value in
A1
> is only calculated there for the benefit of the macro, you should instead
> calculate the value in the macro.
>
>
>
> CALCULATIONS
>
> ' To include the calculation you have in A1 in your macro itsef, you could
> do this:
>
> Dim DataSetCount As Long
>
> DataSetCount = WorksheetFunction.CountA(Range("B:B")) - 2
>
>
>
> AVOIDING SELECTION
>
> The basic principle to replacement of selecting cells and referring to the
> selection is: (1) when you want to select cells, instead assign the cells
to
> a Range variable.  (2) when you want to refer to the selection, instead
> refer to the Range variable.  (3) when you want to extend or modify the
> selection, instead extend or modify the Range Variable.
>
>
>
> E.g. , I will demonstrate replacement of the uses of Select and Selection
in
> the following code.
>
>
>
> 'Your current version:
>
> Range("E4").Select
>
> Range(Selection, Selection.End(xlToRight)).Select
>
> Range(Selection, Selection.End(xlDown)).Select
>
>
>
> ALTERNATIVES FOR IDENTIFYING REGIONS
>
> New Version without Select or Selection, and further simplified by
replacing
> RANGE.End properties with a single use of RANGE.CurrentRegion, which has
> subtle differences but it sounds it will suit your purposes at least as
well
> (it casts a slightly larger net since it refers to the rectangular range
> containing a referenced cell/range with any path of contiguously used
cells
> in it,., This ordinarily represents a table of data well).
>
>
>
> Dim DataSetSource As Range
>
> Set DataSetSource = Range("E4").CurrentRegion
>
>
>
> A second look at your code, and I am not certain that my example using
> CurrentRegion will work for you after all, though you can try it.  If
there
> is data anywhere in column D, next to your data, it will get included too.
> Also included will be anything touching the area in rows 1-3.  Two of
manys
> alternatives: (1) Use the RANGE.End properties, similar to how you already
> were, (2) Use RANGE.Find to find the lower right cell instead of the two
> Ends.  This works in reverse and assumes the worksheet is blank below and
to
> the right of your data.  An advantage is that it is insensitive to gaps in
> the data).
>
>
>
> 'E.g. 1: Simple version using End to determine right and bottom extents.
> This works out the same as your original code.
>
> Dim DataSetSource As Range
>
> With Range("E4")
>
>     Set DataSetSource = Range(.Cells, .End(xlToRight).End(xlDown))
>
> End With
>
>
>
> 'E.g. 2: Using a hybrid approach with RANGE.Find to find the bottom row.
>
> Dim DataSetSource As Range
>
> Dim StartRow As Long
>
> With Range("E4")
>
>     Set DataSetSource = Range(.Cells, .End(xlToRight))
>
> End With
>
> StartRow = DataSetSource.EntireRow.Row
>
> With DataSetSource
>
>     Set DataSetSource = .Resize(Rows.Count - StartRow + 1, .Columns.Count)
>
>     Set DataSetSource = .Resize(.Find("*", LookIn:=xlValues,
> SearchDirection:=xlPrevious).EntireRow.Row - StartRow + 1, .Columns.Count)
>
> End With
>
>
>
> RELIABILITY
>
> For reliable code, you should "qualify" all object references sufficiently
> to be unambiguous.  Unqualified references like Range(..) instead of
> WORKBOOK.WORKSHEET.Range() are prone to misinterpretation.  VBA may make
> different assumptions depending on the context of your code and what
> worksheet is active.  A qualified reference specifies all parent objects,
> although it is acceptable to leave out the topmost parent -- the library
> name -- for objects available by default in Excel in the 99% of cases
where
> it works without the reference (For example, there is usually no need to
> prefix anything with "VBA.", and in most cases no need to prefix members
of
> the Application object with "Application.".  Unqualified references can
make
> debugging your code difficult, too, since you will have to make a lot of
> assumptions as you examine the code, some of which may be incorrect.
Also,
> using plenty of well-named and typed variables can help make your code
> easier to understand as well as run faster whenever you refer to the
> variable more than once insterad of redefining whatever its value or
object
> would be each time you need it.  If you perform the same actoins
repeatedly
> in your macro, you should seek to structure your code such that repetions
> are minimized.  This can be done using loops, If/Then statements to handle
> variations, and encapsulating the reptitive code into separate procedures
> (Functions or Subs), or Classes (Classes are more advanced).  Try to take
> the approach that makes the most streamlined code, even if the path taken
to
> your desired end result is different than that you would take if doing the
> task manually.  It takes experience and/or study to get better at that.
>
>
>
> 'I think the below will perform the same functions as your original code,
> but untested.
>
> 'For the loop I have assumed you want to just continue until no more
> datasets are found.
>
> 'I treated Data Set 1 and Data Set 2 as an irrelevant distinction, since
> your code handles
>
> 'both the same and one is right above the other one that you want to loop.
>
> Sub ShiftDataSets
>
> Dim Ws As Worksheet
>
> Dim Position As Range
>
>
>
>     Set Ws = ActiveSheet
>
>     'Or if you want to act on a specific sheet uncomment and change below
> line:
>
>     'Set Ws = ThisWorkbook.Worksheets("Sheet Name")
>
>
>
>     Set Position = Ws.Range("E4")
>
>     Do While Not IsEmpty(Position.Value)
>
>         ShiftDataSet Position
>
>         Set Position = Position.Offset (4, 1)
>
>     Loop
>
> End Sub
>
>
>
> ' ShiftData's Position is returned modified with end position
>
> Sub ShiftDataSet (ByRef Position As Range)
>
> Dim DataSetSource As Range
>
> Dim NewRow As Range
>
>
>
>     Set Ws = Position.Parent
>
>     With Position
>
>         Set DataSetSource = Ws.Range(.Cells, .End(xlToRight).End(xlDown))
>
>     End With
>
>     With DataSetSource
>
>         .Offset(0, -1).Value = .Value
>
>         .Columns(.Columns.Count).Clear
>
>         Set NewRow = .Rows(1).EntireRow.Offset(3, 0)
>
>     End With
>
>     NewRow.Insert
>
>     Set Position = NewRow.Cells(1)
>
>     Position.Value = "variance"
>
> End Sub
>
>
>
> FURTHER IMPROVEMENTS
>
> It might be possible to shift all the datasets at once, making it much
> faster if you have many datasets.
>
> [postscript: that is the tactic of the asaShiftDataFast() routine near the
> beginning of this email.]
>
>
>
> We could modify the loop for inserting rows/"variance", for even better
> performance like so:
>
> 'option 1 - a string of comma separated row ranges in the form
> "4:4,7:7,10:10" will not exceed 255 characters - fastest
>
> Dim InsertRangeAddress As Variant
>
> Dim InsertRange As Range
>
>     InsertRangeAddress = Null
>
>     For Row = 4 To StopRow Step 3
>
>         InsertRangeAddress = (InsertRangeAddress + ",") & Row & ":" & Row
>
>     Next Row
>
>     Set InsertRange = Ws.Range(InsertRangeAddress)
>
>     InsertRange.Insert
>
>     Intersect(DataSetDestination.Columns(1).EntireColumn,
> InsertRange).Offset(-1, 0).Value = "variance"
>
>
>
> 'option 2 - like option 1, but handles excessive rows by working in groups
> of 255 characters or less (still very fast)
>
> ' works for any number of rows
>
> Dim InsertRangeAddress As Variant
>
> Dim LastInsertRangeAddress As Variant
>
> Dim InsertRange As Range
>
> Dim Column1 As Range
>
>     Set Column1 = DataSetDestination.Columns(1).EntireColumn
>
>     LastInsertRangeAddress = Null
>
>     Row = StopRow
>
>     Do Until Row <= 1
>
>         InsertRangeAddress = (LastInsertRangeAddress + ",") & Row & ":" &
> Row
>
>         If Len(InsertRangeAddress) > 255 Then
>
>             GoSub InsertVariance
>
>             Row = Row + 3
>
>         ElseIf Row <= 4 Then
>
>             GoSub InsertVariance
>
>         End If
>
>         LastInsertRangeAddress = InsertRangeAddress
>
>         Row = Row - 3
>
>     Loop
>
>
>
>     Exit Sub
>
>
>
> InsertVariance:
>
>     Set InsertRange = Ws.Range(LastInsertRangeAddress)
>
>     InsertRange.Insert
>
>     Intersect(Column1, InsertRange).Offset(-1, 0).Value = "variance"
>
>     InsertRangeAddress = Null
>
>     Return
>
>
>
> Another alternative is to use Union() to assemble one big InsertRange and
> then perform a single insert.  This works for any number of rows, but the
> more rows there are, the slower the Union operation is to add an
additional
> row to the range, so for many rows it would be slower than the two options
> detailed above.
>
>
>
> ###########################################
>
> Asa
>
>
>
>
>
> From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
> On Behalf Of Pehrson, Dave
> Sent: Thursday, October 18, 2012 11:19 AM
> To: excel-macros@googlegroups.com
> Cc: dguille...@gmail.com
> Subject: RE: $$Excel-Macros$$ Re: Request for support for a looping macro
>
>
>
> Don,  I apologize for a delayed response,   your response was shuffled my
> "junk" mail, and I had overlooked it.  I appreciate you looking at my
> request.  I'm not a programmer, so you are right on,  I often do things
the
> hard way, not knowing the easy way.  Let me re-think the request and
better
> respond.
>
>
>
> Again thanks so very much looking at the request
>
>
>
> Dave
>
>
>
> From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
> On Behalf Of Don Guillett
> Sent: Tuesday, October 02, 2012 3:49 PM
> To: excel-macros@googlegroups.com
> Cc: 'ashish koul'
> Subject: $$Excel-Macros$$ Re: Request for support for a looping macro
>
>
>
> Methinks you are making this much more difficult than necessary.
>
> Either fully explain what you want with before/after example
>
> If all else fails, send file to dguillett1 @gmail.com
>
> On Tuesday, October 2, 2012 4:33:57 PM UTC-5, Diamond Dave wrote:
>
>
>
> Attached is a file which contains a Macro (Shift Data).
>
> There is a variable number of data sets (all the same configuration)
defined
> in Cell A1 with the formula A1=Counta(B:B)-2  which defines the actual
> number of data sets.
>
>
>
> The macro (below) defines what needs to be done to the first and Second
data
> set
>
>
>
>   'Data Set 1
>
>
>
>    Range("E4").Select
>
>     Range(Selection, Selection.End(xlToRight)).Select
>
>     Range(Selection, Selection.End(xlDown)).Select
>
>     Selection.Cut
>
>     ActiveCell.Offset(0, -1).Select
>
>     ActiveSheet.Paste
>
>     ActiveCell.Offset(3, 0).Select
>
>     Selection.EntireRow.Insert
>
>     ActiveCell.FormulaR1C1 = "variance"
>
>     ActiveCell.Offset(4, 1).Select
>
>
>
>  'Data Set 2
>
>
>
>     Range(Selection, Selection.End(xlToRight)).Select
>
>     Range(Selection, Selection.End(xlDown)).Select
>
>     Selection.Cut
>
>     ActiveCell.Offset(0, -1).Select
>
>     ActiveSheet.Paste
>
>     ActiveCell.Offset(3, 0).Select
>
>     Selection.EntireRow.Insert
>
>     ActiveCell.FormulaR1C1 = "variance"
>
>     ActiveCell.Offset(4, 1).Select
>
>
>
> How would I write a loop which will perform the function for "Data SET 2"
> the number of times shown in cell A1?
>
>
>
> Your Support is greatly appreciated
>
> David Pehrson
>
> --
> Join official facebook page of this forum @
> https://www.facebook.com/discussexcel
>
> FORUM RULES (1120+ members already BANNED for violation)
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
will
> not get quick attention or may not be answered.
>
> 2) Don't post a question in the thread of another member.
>
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
>
> 4) Acknowledge the responses you receive, good or bad.
>
> 5) Cross-promotion of, or links to, forums competitive to this forum in
> signatures are prohibited.
>
> 6) Jobs posting is not allowed.
>
> 7) Sharing copyrighted ebooks/pirated ebooks/their links is not allowed.
>
> NOTE : Don't ever post personal or confidential data in a workbook. Forum
> owners and members are not responsible for any loss.
> ---
> You received this message because you are subscribed to the Google Groups
> "MS EXCEL AND VBA MACROS" group.
> To post to this group, send email to excel-macros@googlegroups.com.
> To unsubscribe from this group, send email to
> excel-macros+unsubscr...@googlegroups.com.
>
>
>
> --
> Join official facebook page of this forum @
> https://www.facebook.com/discussexcel
>
> FORUM RULES (1120+ members already BANNED for violation)
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
will
> not get quick attention or may not be answered.
>
> 2) Don't post a question in the thread of another member.
>
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
>
> 4) Acknowledge the responses you receive, good or bad.
>
> 5) Cross-promotion of, or links to, forums competitive to this forum in
> signatures are prohibited.
>
> 6) Jobs posting is not allowed.
>
> 7) Sharing copyrighted ebooks/pirated ebooks/their links is not allowed.
>
> NOTE : Don't ever post personal or confidential data in a workbook. Forum
> owners and members are not responsible for any loss.
> ---
> You received this message because you are subscribed to the Google Groups
> "MS EXCEL AND VBA MACROS" group.
> To post to this group, send email to excel-macros@googlegroups.com.
> To unsubscribe from this group, send email to
> excel-macros+unsubscr...@googlegroups.com.
>
>
>
> --
> Join official facebook page of this forum @
> https://www.facebook.com/discussexcel
>
> FORUM RULES (1120+ members already BANNED for violation)
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
will
> not get quick attention or may not be answered.
>
> 2) Don't post a question in the thread of another member.
>
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
>
> 4) Acknowledge the responses you receive, good or bad.
>
> 5) Cross-promotion of, or links to, forums competitive to this forum in
> signatures are prohibited.
>
> 6) Jobs posting is not allowed.
>
> 7) Sharing copyrighted ebooks/pirated ebooks/their links is not allowed.
>
> NOTE : Don't ever post personal or confidential data in a workbook. Forum
> owners and members are not responsible for any loss.
> ---
> You received this message because you are subscribed to the Google Groups
> "MS EXCEL AND VBA MACROS" group.
> To post to this group, send email to excel-macros@googlegroups.com.
> To unsubscribe from this group, send email to
> excel-macros+unsubscr...@googlegroups.com.
>
>

-- 
Join official facebook page of this forum @
https://www.facebook.com/discussexcel

FORUM RULES (1120+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please
Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will
not get quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security
measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in
signatures are prohibited. 

6) Jobs posting is not allowed.

7) Sharing copyrighted ebooks/pirated ebooks/their links is not allowed.

NOTE  : Don't ever post personal or confidential data in a workbook. Forum
owners and members are not responsible for any loss.
--- 
You received this message because you are subscribed to the Google Groups
"MS EXCEL AND VBA MACROS" group.
To post to this group, send email to excel-macros@googlegroups.com.
To unsubscribe from this group, send email to
excel-macros+unsubscr...@googlegroups.com.


-- 
Join official facebook page of this forum @ 
https://www.facebook.com/discussexcel

FORUM RULES (1120+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in 
signatures are prohibited. 

6) Jobs posting is not allowed.

7) Sharing copyrighted ebooks/pirated ebooks/their links is not allowed.

NOTE  : Don't ever post personal or confidential data in a workbook. Forum 
owners and members are not responsible for any loss.
--- 
You received this message because you are subscribed to the Google Groups "MS 
EXCEL AND VBA MACROS" group.
To post to this group, send email to excel-macros@googlegroups.com.
To unsubscribe from this group, send email to 
excel-macros+unsubscr...@googlegroups.com.


Reply via email to