|
Hi Dan,
If this is a one time deal, you can temporarily insert a new column and
paste this formula into the rows of that column:
=IF(AND(ISERROR(SEARCH(D1,"SRC3 UUMC PN FCR1")),A1=22),LEFT(J1,2) & "78"
& MID(J1,5,6),J1)
Then select those values and Copy them to the clipboard, and Paste just
the values back to column J, and finally, delete the temporary column.
Or you could write a macro, something like:
Sub FixColJ()
' Conditionally fix values in column J
Dim A1value As String
Dim D1value As String
For Each c In Selection
A1value = c.Offset(0, -9)
D1value = c.Offset(0, -6)
If InStr(D1value, "SRC3 UUMC PN FCR1") = 0 And A1value = 22 Then
c.Value = Left(c.Value, 2) & "78" & Mid(c.Value, 5, 6)
End If
Next
MsgBox "J1 column modified"
End Sub
--
*Peter Dow* /
Dow Software Services, Inc.
909 793-9050
pdow@xxxxxxxxxxxxxxx <mailto:pdow@xxxxxxxxxxxxxxx> /
On 11/16/2010 7:36 AM, Dan wrote:
I have a spreadsheet with approx. 500 rows of data. I need to update athe
substring in a column conditioned by values in that column and in another
column. If it were SQL, I might use:
Update "worksheet"
set J1 = substr(J1, 1, 2) + '78' + substr(J1, 5, 6)
where D1 not in ('SRC3', 'UUMC', 'PN', 'FCR1')
and A1 = 22
where J1, D1,& A1 are individual cells in the same row (#1); and I need
this repeated for all 500 rows of data. Essentially, I need to replace
3rd& 4th character in J1 with '78' when certain conditions are met.I
I have no idea how to accomplish this in Excel. I'm guessing a macro is
involved, but my knowledge of them is limited.
Any help or even links to online pointers would be greatly appreciated.
googled a bunch of terms, but came up with a lot of external data import,--
ODBC type of stuff.
- Dan
This is the PC Technical Discussion for iSeries Users (PcTech) mailing list
To post a message email: PcTech@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/pctech
or email: PcTech-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/pctech.
As an Amazon Associate we earn from qualifying purchases.
This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].
Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.