[OPEN-ILS-DEV] ***SPAM*** Re: ***SPAM*** Re: Removing URLS from 856

Liam Whalen whalen.ld at gmail.com
Tue Apr 2 23:32:32 EDT 2013


For the first SELECT you can use something like SELECT regexp_replace(marc,E'<datafield[^>]+?tag="856".+?<subfield code="9">HCC</subfield>(?:(?!</datafield>).)*</datafield>','','g') FROM biblio.record_entry WHERE marc ~ '<datafield[^>]+tag="856"(?:(?!</datafield>).)*</datafield>'

That should give you your datafields without HCC.  If you can search through the results for HCC and find any examples of HCC left, then you can improve the regex to catch them.  Or opt for another non-regex route.  If there are no HCC's left, then check to make sure you aren't missing some due to something else in the WHERE regex.

SELECT no_hcc FROM 
	(SELECT  regexp_replace(marc,E'<datafield[^>]+?tag="856".+?<subfield code="9">HCC</subfield>(?:(?!</datafield>).)*</datafield>','','g') AS no_hcc FROM biblio.record_entry WHERE marc ~ '<datafield[^>]+tag="856"(?:(?!</datafield>).)*</datafield>' )
WHERE no_hcc ~* <subfield code="9">HCC</subfield>'

Its been a while since I've written that type SQL, and I don't have an Evergreen database to test it on.  So, that may not work exactly as written, but that is the general idea on how to double check mass db updates.  The idea with the last WHERE clause is to look for the least amount of data that could catch the HCC subfield.  If you are willing to sort through some false positives, it might be worthwhile changing the where to '>HCC<' or even 'HCC', just to make sure you are getting everything.  The idea being to look for malformed MARCXML.  As well, I put a case insensitive regex search (~*) in the last WHERE clause. If you are sure all the HCCs are upper case you will not need that.

Liam


On 2013-04-02, at 10:20 PM, Liam Whalen <whalen.ld at gmail.com> wrote:

> You could also use negative lookahead to capture the 856 fields where subfield 9 is not at the end.
> 
> regexp_replace(marc,E'<datafield[^>]+?tag="856".+?<subfield code="9">HCC</subfield>(?:(?!</datafield>).)*</datafield>','','g') 
> 
> I did not test this much either, but it does pick up only your HCC fields in the data you provided below.  That being said, I was always surprised when using regex on large sets of data.  A good way to test this is to run it as a SELECT first to try and pull records with that regex, then grep through them to make sure you are only getting rid of the data you want.  Then for completeness, do another select for 856 fields with a WHERE clause using your regex to exclude the items you just verified for completeness, and grep through those results to make sure you are not missing any 9 = HCC fields.
> 
> Liam
> 
> 
> On 2013-04-02, at 10:14 AM, Mike Rylander <mrylander at gmail.com> wrote:
> 
>> On Tue, Apr 2, 2013 at 9:43 AM, Tim Spindler <tjspindler at gmail.com> wrote:
>> This is the regex I was trying but in testing it wasn't working.
>> 
>> regexp_replace(marc,E'<datafield[^>]*?tag="856"+?<subfield code="9">HCC</subfield></datafield>','','g') 
>> 
>> 
>> Perhaps something like: regexp_replace(marc,E'<datafield[^>]+?tag="856".+?<subfield code="9">HCC</subfield></datafield>','','g')
>> 
>> As long as subfield 9 is at the end of all the datafields, that should work.  It's not heavily tested.
>>  
>> --miker
>> 
>> 
>> On Tue, Apr 2, 2013 at 9:41 AM, Tim Spindler <tjspindler at gmail.com> wrote:
>> Mike, 
>> 
>> For the batch update, it is about 6000 records with bucket, I didn't think Evergreen could handle that many in a bucket.
>> 
>> Tim
>> 
>> 
>> On Tue, Apr 2, 2013 at 9:20 AM, Mike Rylander <mrylander at gmail.com> wrote:
>> If your removal code is regexp-based, you'll just need to match on HCC in the middle of the "find for removal" regexp.  Alternatively, you could apply the batch MARC update function to a bucket or CSV file full of the records.  That has the ability to modify records conditionally, based on subfield content within a datafield.
>> 
>> --miker
>> 
>> 
>> 
>> On Tue, Apr 2, 2013 at 9:12 AM, Tim Spindler <tjspindler at gmail.com> wrote:
>> We have a library that wants to reload its Films on Demand records.  These records have multiple 856s for other institutions with the subfield 9 associated with their shortname.  What would the best way be to remove these for instance.   I have created a list of the records needing updating in the staging table.  Here is an example of the of he 856.  I have code that can remove all the 856s but am having trouble removing just one.  We just want to remove the one for HCC (although I'll take suggests for removing the duplicate QCC lines also)
>> 
>> <datafield tag="856" ind1="4" ind2="0"><subfield code="y">Click here to access this film online (MCLA students, faculty, and staff only)</subfield><subfield code="u">http://libproxy.mcla.edu:2048/login?url=http://digital.films.com/PortalPlaylists.aspx?aid=11580&amp;xtid=152</subfield><subfield code="9">MCLA</subfield></datafield>
>> <datafield tag="856" ind1="4" ind2="0"><subfield code="u">http://ezhc.ez.cwmars.org:4000/login?url=http://digital.films.com/PortalPlaylists.aspx?aid=9206&amp;xtid=152</subfield><subfield code="y">Click here to access this film online (HCC Students and Staff only)</subfield><subfield code="9">HCC</subfield></datafield>
>> <datafield tag="856" ind1="4" ind2="0"><subfield code="y">Click here to access this film online (QCC studetns, faculty, &amp; staff only)</subfield><subfield code="u">http://ezqc.ez.cwmars.org:5200/login?url=http://digital.films.com/PortalPlaylists.aspx?aid=19277&amp;xtid=152</subfield><subfield code="9">QCC</subfield></datafield>
>> <datafield tag="856" ind1="4" ind2="0"><subfield code="u">http://ezhc.ez.cwmars.org:4000/login?url=http://digital.films.com/PortalPlaylists.aspx?aid=9206&amp;xtid=152</subfield><subfield code="y">Click here to access this film online (HCC Students and Staff only)</subfield><subfield code="9">HCC</subfield></datafield>
>> <datafield tag="856" ind1="4" ind2="0"><subfield code="y">Click here to access this film online (QCC studetns, faculty, &amp; staff only)</subfield><subfield code="u">http://ezqc.ez.cwmars.org:5200/login?url=http://digital.films.com/PortalPlaylists.aspx?aid=19277&amp;xtid=152</subfield><subfield code="9">QCC</subfield></datafield>
>> 
>> 
>> -- 
>> Tim Spindler
>> tjspindler at gmail.com
>> 
>> P   Go Green - Save a tree! Please don't print this e-mail unless it's really necessary.
>>  
>> 
>> 
>> 
>> -- 
>> Mike Rylander
>>  | Director of Research and Development
>>  | Equinox Software, Inc. / Your Library's Guide to Open Source
>>  | phone:  1-877-OPEN-ILS (673-6457)
>>  | email:  miker at esilibrary.com
>>  | web:  http://www.esilibrary.com
>> 
>> 
>> 
>> -- 
>> Tim Spindler
>> tjspindler at gmail.com
>> 
>> P   Go Green - Save a tree! Please don't print this e-mail unless it's really necessary.
>>  
>> 
>> 
>> 
>> -- 
>> Tim Spindler
>> tjspindler at gmail.com
>> 
>> P   Go Green - Save a tree! Please don't print this e-mail unless it's really necessary.
>>  
>> 
>> 
>> 
>> -- 
>> Mike Rylander
>>  | Director of Research and Development
>>  | Equinox Software, Inc. / Your Library's Guide to Open Source
>>  | phone:  1-877-OPEN-ILS (673-6457)
>>  | email:  miker at esilibrary.com
>>  | web:  http://www.esilibrary.com
> 

-------------- next part --------------
An HTML attachment was scrubbed...
URL: <http://libmail.georgialibraries.org/pipermail/open-ils-dev/attachments/20130402/a7206a7c/attachment-0001.htm>


More information about the Open-ils-dev mailing list