Beefy Boxes and Bandwidth Generously Provided by pair Networks
Don't ask to ask, just ask
 
PerlMonks  

Win32::OLE Excel search and replace commas

by generator (Pilgrim)
on Oct 11, 2010 at 07:57 UTC ( [id://864556]=perlquestion: print w/replies, xml ) Need Help??

generator has asked for the wisdom of the Perl Monks concerning the following question:

Monks, I've been attempting to prep user provide Excel spreadsheets for use as data input sources. I've been manually processing these spreadsheets for some months but now want to programatically address this.

I'll be importing the data as CSV files. I've been able to produce the CSV files from the user provided Excel files, but cannot seem to delete all instances of commmas within them.

I'd expected this to be a simple proceedure using Win32::OLE.

All other aspects of this project are working. I just need to know how to search an Excel spreadsheet and eliminate (or replace with nothing) every instance of a comma in any field value.

Thanks for any guidance you can suggest.
<><

generator

  • Comment on Win32::OLE Excel search and replace commas

Replies are listed 'Best First'.
Re: Win32::OLE Excel search and replace commas
by Corion (Patriarch) on Oct 11, 2010 at 08:05 UTC
Re: Win32::OLE Excel search and replace commas
by davies (Prior) on Oct 11, 2010 at 09:34 UTC
    It's not quite that simple. Excel, at least in English-based locales, uses commas to separate formula options. If you try to replace commas with nothing, Excel will stop at the first critical comma in a formula and complain. Non-critical commas will probably result in wrong results or #NAME. Therefore, if you are in such a locale, you have two options that are immediately obvious to me. One is to change locale to something that uses a different character (I think France uses semicolons, for example). The other is to copy everything and Paste Special Values. Then you can use the usual Excel find & replace tool, Ctrl-H, before writing the CSV.

    An option here is to use a special character, something you wouldn't expect to see anywhere. Then, once you have imported the data into Perl, you can replace every special character with a comma and get back to the embedded commas which are, I suspect, what you are having trouble with. There's an interesting thread on CSVs still active at problems parsing CSV.

    Regards,

    John Davies
      Thanks for the feedback. I didn't find a way to run a search and replace using OLE. (I was attempting to replicate the manual steps I took, while manually editing these files).

      I did, however, find a solution. I extracted the cell values then ran a substitute =~ s/,//; on the scalar value before writing it to a text file, followed by a comma.

      #!c:/perl/bin/perl.exe use strict; use warnings; use Win32::OLE qw(in with); use Win32::OLE::Const 'Microsoft Excel'; $Win32::OLE::Warn = 3; open (OUTPUT,">>","c:/assess/output.txt"); my $Excel = Win32::OLE->GetActiveObject ('Excel.Application') || Win32::OLE->new('Excel.Application', 'Quit'); my $Book = $Excel->Workbooks->Open ("C:/assess/assessment.xls"); my $Sheet = $Book->Worksheets(1); my $LastRow = $Sheet->UsedRange->Find({What=>"*", SearchDirection=>xlPrevious, SearchOrder=>xlByRows})->{Row}; my $array = $Sheet->Range("B2:"."F".$LastRow)->{'Value'}; foreach my $ref_array (@$array) { foreach my $scalar (@$ref_array) { $scalar =~ s/,//; print OUTPUT "$scalar,"; } print OUTPUT "\n"; } $Book->Close;

      Your warning regarding the use of commas in formulas was wise but in this case irrelevant. The subsequent processing used only integer values associated with unit cost, unit rate and account code (text string). All fields with formulas are ignored.

      Thanks again for taking the time to reply. It ain't pretty but it will do the job.

      <><

      generator

        Ah, the joys of having code to look at. You're going to a lot of trouble to generate the CSV, when Excel will do it for you automatically.
        use strict; use warnings; use Win32::OLE; my $Excel=Win32::OLE->new('Excel.Application'); $Excel->{Visible}=1; $Excel->{DisplayAlerts}=0; my $Book = $Excel->Workbooks->Open("F:\\assess\\assessment.xls") or di +e "Can't open file"; $Book->SaveAs({Filename => "F:\\Assess\\Assessment.csv", FileFormat => 6, #xlCSV, CreateBackup => 0}); $Excel->Quit;
        A few points. First, indenting code within if blocks, loops etc. will make it easier for you to understand what your code is doing in a few months' time. Second, I commented in Re^3: Win32::Ole excel external data range on both with and relying on an existing instance of Excel. I suspect both you and the other OP copied code from the same place. Third, the thread I mentioned earlier describes dealing with embedded commas and quotes, but the general rule for CSVs is that you can embed a comma in quotes. The output of my test file is:
        1,2,3,4 2,"Who, What?",4,5 3,4,5,6 4,5,6,7
        Update:
        If, despite this, you really need to get rid of commas, the following code will remove commas from text:
        use strict; use warnings; use Win32::OLE; my $Excel=Win32::OLE->new('Excel.Application'); $Excel->{Visible}=1; my $Book = $Excel->Workbooks->Open("F:\\assess\\Lorem.xls") or die "Ca +n't open file"; $Excel->Cells->Replace({ What => ",", Replacement => ""});
        This won't get rid of formatting commas in numbers. To do that, you will need to change the formats. But from your code, you're looking at the underlying numbers anyway, rather than printing a file.
        End of update

        Regards,

        John Davies

Log In?
Username:
Password:

What's my password?
Create A New User
Domain Nodelet?
Node Status?
node history
Node Type: perlquestion [id://864556]
Approved by igelkott
help
Chatterbox?
and the web crawler heard nothing...

How do I use this?Last hourOther CB clients
Other Users?
Others having a coffee break in the Monastery: (3)
As of 2024-04-19 19:44 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?

    No recent polls found