All payments in a date range with quick transaction view

A SQL report for Koha ILS

Yesterday was the last day of the year, when Sri Ashish Kumar Barik the young and enthusiastic librarian at Midnapore City College requested for a new custom SQL report that would allow him:

To see every payment made by every user in a given date range, sorted by MM/YY. It should show every type of payment made e.g. overdue fines, lost book fees, library card replacement. Basically everything that was charged to and paid by a patron

In this blog post we share it with all, so that others looking for something similar can have a ready template for their use. It’s our way to saying thank you and Happy New Year 2019 to all our readers, clients and well-wishers.

Putting it together

The report uses three tables in the Koha database – (a) accountlines; (b) borrowers and (c) categories.

The report adds a quick transaction view link next to each and every payment. For library staff wanting to find out the details of a particular payment, with this report that information is just a single click away.

The report metadata
Report name List all payments made by patrons between two dates
Report group Accounts
Notes List all payments made by patrons between two dates, sorted by date and patron name.
The SQL statement
SELECT 
    CONCAT("<a href=\"/cgi-bin/koha/members/boraccount.pl?borrowernumber=", T1.borrowernumber, "\" target=\"_blank\">View Transaction</a>") AS 'Click to view'
    , T2.cardnumber AS 'Card No.'
    , CONCAT(T2.firstname, " ", T2.surname) AS 'Name'
    , T3.description AS 'Category'
    , CONCAT(SUBSTRING(MONTHNAME(T1.timestamp), 1,3), " ", YEAR(T1.timestamp)) AS 'Billing Period'
    , DATE_FORMAT(DATE(T1.timestamp), "%d/%m/%Y") AS 'Txn Date'
    , CONCAT("₹", LPAD(REPLACE(ROUND(T1.amount, 2),"-", ""), 8, " ")) AS 'Paid' 
FROM 
    `accountlines` T1 
     LEFT JOIN borrowers T2 USING (borrowernumber) 
    LEFT JOIN categories T3 USING (categorycode) 
WHERE 
    T1.accounttype="PAY" 
    AND
   DATE(T1.timestamp) BETWEEN <<From date|date>> AND <<To date|date>> 
ORDER BY DATE(T1.timestamp), CONCAT(T2.firstname, " ", T2.surname)
See it in action

Here is a short 2 minute video of it for those who want to see it action.

Wishing everyone a Happy New Year 2019.

Extracting patron images from Koha DB

This is part of the series of blog posts on how to extract your data from a Koha system where you unable to access the DB directly, but where you have “superlibrarian” access. In this part, we talk about extracting the patron images stored inside the patronimage table in your Koha database.

Prequisites

  • You should be comfortable using the GNU/Linux command line
  • Familiarity with SQL syntax
  • The Koha DB schema reference for your version of Koha
  • A Linux system with cURL and LibreOffice installed
  • Superlibrarian userid and password of your Koha instance

Modus operandi

  1. Use the Koha Reports module to download the list of the borrowernumbers of patrons having their image in the db
  2. Remove the header line and save it as a text file, with one borrowernumber per line
  3. Use cURL to get the CGISESSID cookie using the authentication SVC API call
  4. Execute the BASH script, passing the authenticated session id and the file holding the list of borrowernumbers as command line parameters
  5. Use the Koha Reports module to generate the IDLINK.txt batch patron image uploader file

The background

Patron images in Koha are stored in the patronimage table of the database. The table has following schema:

Column Type Size Parents Comments
borrowernumber int 10 borrowers the borrowernumber of the patron this image is attached to (borrowers.borrowernumber)
mimetype varchar 15   the format of the image (png, jpg, etc)
imagefile mediumblob 16777215   the image

A blob is a “binary large object” which means it is not a text field. The contents won’t make any sense if we used the report module to SELECT imagefile FROM patronimage. This brings cURL into the picture.

The patron image is served on the OPAC / staff client using the patronimage.pl Perl script using an URL like this: http://<your_instance>/cgi-bin/koha/members/patronimage.pl?borrowernumber=<borrowernumber>.

But before we can run cURL on this URL, we must do one more thing. We need our BASH script to login using our superlibrarian userid and password using Koha authentication web service API call.

We need to do this for two reasons: (a) login into our Koha instance with superlibrarian access and (b) get hold of the CGISESSID cookie.

Putting it all together

  1. A simple SQL report as given below with fetch us the borrowernumber of patrons with their image stored in the DB.

    SELECT borrowernumber FROM patronimage

    We will download the result as Open Document spreadsheet.

    Next we copy and save the list of patron borrowernumbers into a text file (let’s call it list-of-pix.txt), with one borrowernumber per line.

  2. Lets put together our small BASH script. We shall call it get_pix.sh.
    #!/bin/bash
    
    mkdir patronimages
    
    while read LINE
        do  curl -b CGISESSID=$1  -o ./patronimages/$LINE.png http://<your_instance>/cgi-bin/koha/members/patronimage.pl?borrowernumber=$LINE
    done < $2

    NOTE: <your_instance> need to be changed with **your** actual server URL.
    Make the script executable by running chmod a+x get_pix.sh.

  3. From the command-line run the following command:
    $ curl -i http://<your_instance>/cgi-bin/koha/svc/authentication -d 'userid=<yourid>&password=<yourpass>'

    If we had put in the correct information, we shall see something like this:

    HTTP/1.1 200 OK
    Date: Thu, 20 Dec 2018 09:53:02 GMT
    Server: Apache/2.4.18 (Ubuntu)
    Set-Cookie: CGISESSID=4a732ae75d8991a994d7ad0df584f84c; path=/; HttpOnly
    Vary: Accept-Encoding
    Transfer-Encoding: chunked
    Content-Type: text/xml; charset=ISO-8859-1
    
    <?xml version='1.0' standalone='yes'?>
    <response>
      <status>ok</status>
    </response>

    This gives us the two things we need for the next step: (a) the CGISESSID and (b) the status as OK. OK signifies that we were successfully logged in.

  4. Now we run the get_pix.sh script
    ./get_pix.sh f03a894f1885e891e30f6d40e6e9838c ./list-of-pix.txt

    And we shall see the patron images getting downloaded.

  5. Once the patron images have all been downloaded to patronimages folder created by the get_pix.sh script, its time to generate the IDLINK.txt file, which we will place in the aforementioned patronimages folder. Again, we shall turn to Koha's Reports module with this small SQL script:
    SELECT CONCAT(borrowers.cardnumber,", ", patronimage.borrowernumber, ".png") AS 'IDLINK'
      FROM patronimage 
      LEFT JOIN borrowers ON patronimage.borrowernumber=borrowers.borrowernumber

    This will generate our listing for the IDLINK.txt. If you are not sure about what IDLINK.txt does, please read up from here.

  6. Download the report as Open Document Spreadsheet, remove the header line and copy the rest into a text file and save it as IDLINK.txt in the patronimages folder.
  7. Zip up the patronimages folder as mentioned here and we have the patron images ready for a batch upload.

Display the totals for fines & fees, payments made, the outstanding, written off and forgiven amounts between a specified date range

A nifty single line SQL report for accounting using Koha.

Earlier this week, Sri Kalipada Jana, librarian at our client-partner Basanti Devi College, Kolkata, filed a new custom SQL report request. He wanted a report that did the following:

To list the total fines accrued, total paid so far and the total outstanding fines / fee between 02 (two) given dates.

Now, the readers of this blog who are acquinted with ready-made, user contributed SQL report library on the Koha Community wiki will know that there are a quite a few reports available that generate reports similar to Kalipada’s requirement. However these ready-made SQL reports usually generate this data at one data point at a time e.g. one report will provide total fines, another will provide total outstanding fines and so on. Further (and perhaps left as a exercise to the reader) these ready reports usually do not take into account “reversed charges“, “partial payments” entered as credits etc.

The report

The report presents a consolidated, single line of the total fines & Fees (F + FU + N + A + M + L), amount outstanding (F + FU + N + A + M + L), paid (P + C), written off (W) and forgiven (FOR) between a date range. If you wish to learn more about the mnemonics used within the brackets, you should look at the “Hard Coded Values” entry on the Koha Wiki.

By itself, the report is simple, it aggregates the totals presented by 05 (five) SQL sub-queries and shows it together. One interesting thing to note in the report is the use of “runtime variables“. The two run-time variables @FromDate and @ToDate are used to hold the user specified start and end date, instead of asking for the same repeatedly for each sub query.

SELECT * FROM 

(SELECT (@FromDate:=<<From date|date>>) AS 'From (y-m-d)', (@ToDate:=<<To date|date>>) AS 'To (y-m-d)') AS T1, 

(SELECT
    IFNULL(ROUND(SUM(accountlines.amount), 2), "0.00") AS 'Total Fines/Fees' FROM accountlines 
WHERE 
    accounttype IN ('F', 'FU', 'N', 'A', 'M', 'L') AND  DATE(timestamp) BETWEEN @FromDate AND @ToDate) AS T2, 

(SELECT 
    IFNULL(ROUND(SUM(accountlines.amountoutstanding), 2), "0.00") AS 'Total O/S' FROM accountlines 
WHERE 
    accounttype IN ('F', 'FU', 'N', 'A', 'M', 'L') AND  DATE(timestamp) BETWEEN @FromDate AND @ToDate) AS T3, 

(SELECT
    IFNULL(REPLACE(ROUND(SUM(amount),2),"-",""), "0.00") AS 'Paid / Credited'  FROM accountlines 
WHERE
   accounttype IN ('PAY', 'C') AND description NOT LIKE "%Reversed%" AND DATE(timestamp) BETWEEN @FromDate AND @ToDate) AS T4, 

(SELECT
    IFNULL(REPLACE(ROUND(SUM(amount),2),"-",""),"0.00") AS 'Written off'  FROM accountlines 
WHERE 
    accounttype='W' AND DATE(timestamp) BETWEEN @FromDate AND @ToDate) AS T5, 

(SELECT
    IFNULL(REPLACE(ROUND(SUM(amount),2), "-", ""), "0.00") AS 'Forgiven'  FROM accountlines 
WHERE 
    accounttype='FOR' AND DATE(timestamp) BETWEEN @FromDate AND @ToDate) AS T6

Cheers!

L2C2 Technologies extends technological support to KLA for open access journal

L2C2 Technologies to provide OJS software hosting and maintenance along with publishing support to Kerala Library Association for KJIST for the next 5 years.

Earlier today the first open access (OA) LIS journal from Kerala, India – “The Kerala Library Association Journal of Information Science & Technology” (KJIST) was launched with the release of its inaugural issue – Vol. 1 No. 1 July 2018 by Dr. Rajan Gurukkal (Vice Chairman, Kerala State Higher Education Council) at the DLIS Hall, Kerala University Library Building, Thiruvananthapuram.

As the first open access LIS journal being published from Kerala, all articles published in KJIST will be available online at https://www.kjist.in for reading and download. As the technology support partner L2C2 Technologies is providing the journal publishing software hosting & maintenance along with publishing support to Kerala Library Association for KJIST, initially for a period of 5 years. The journal is being hosted using the latest stable version of Open Journal Systems (OJS) journal publishing platform.

While readers are not required to register at the site to read the articles, registered users will receive automatic updates about articles and issues as and when they are published. The privacy policy is GDPR compliant and all personal data submitted by the readers, authors, reviewers and editors are maintained on servers geographically located in India. Mandatory SSL has been implemented for the site, so that when users interact with the site, e.g. when they login or read or download articles, all their transactions remain securely encrypted end-to-end at all times. L2C2 Technologies will also be providing KLA with in-depth usage statistics and data analytics for the online Journal site.

About KJIST

KLA Journal of Information Science and Technology (KJIST) is published twice every year (January and July) in open access (OA) and print formats. It will include original papers, short communications, book reviews and letters pertaining to library science, information science and related fields. The papers included will focus on aspects of exploring, applying, and evaluating new theories and ideas to develop and modernize libraries and enhance library services. It is meant for library professionals, documentation and information professionals, researchers, students and others interested in the library and information science field.

About Kerala Library Association

Formed in 1972 by a group of librarians who strongly felt the need for an independent professional association at the state level to promote the cause of library development, professional standards of librarians, entirely dedicated for libraries and librarians, the Kerala Library Association (KLA) is headquartered at Thiruvananathapuram, the capital of the state of Kerala, India.The association has boldly voiced the sentiments and the views of professionals on several occasions to the concerned authorities. It has successfully projected the need for improving library services in College & Universities. KLA helped the Government to formulate policies in relation to library development in the state.

Chinmaya University partners with L2C2 Technologies for Koha support

We are pleased to extend a warm welcome to the newest member of our growing client-partner family in Southern India – Chinmaya Viswavidyapeeth – a Deemed to be University under UGC, with campuses in Kochi and Pune. The CVV library, which is self-hosted, has gone live on Koha ILS 18.05.04, with server management and Koha maintenance being handled by L2C2 Technologies.

About Chinmaya Viswavidyapeeth

Inaugerated on 9th July, 2017 at Kochi as the Chinmaya Vishwavidyapeeth University for Sanskrit and Indic Traditions, de novo deemed university under the UGC, presently operates from two campuses – the Chinmaya Eswar Gurukula campus at Peppathy in Ernakulam and Chinmaya Naada Bindu Gurukula campus at Kolwan in Pune. It presently offers courses in a number of traditional and contemporary streams.

The university’s motto can be summed up as “विद्यया रक्षिता संस्कृतिः सर्वदा । संस्कृतेर्मानवाः संस्कृता भूरिदा:” (translated:Knowledge protects culture forever; Cultured people share abundantly) in the words of Swami Tejomayananda, founder, Chinmaya Viswavidyapeeth.

Surendranath Law College partners with L2C2 Technologies to automate their library

136 year old Surendranath Law College selects L2C2 Technologies’ Koha support.

We are pleased to extend a warm welcome to the newest member of our growing client-partner family in Eastern India – Surendranath Law College, Kolkata. At 136 years, SNLC is regarded as one the oldest law college of the country. The SNLC library has gone live on Koha ILS 17.11 series on L2C2 Technologies‘s cloud hosting platform.

About Surendranath Law College

Surendranath Law College formerly known as Ripon College) is an undergraduate law college affiliated with the University of Calcutta in Kolkata, India. It was established in 1885 by a trust formed by the nationalist leader, scholar and educationist Surendranath Banerjee, a year after he founded Surendranath College. This is now regarded one of the oldest Law college of the country. Dr. Rajendra Prasad, the first president of the Republic of India is among the several notable alumni of the college.

Source: Wikipedia

AskALibrarian – Koha’s new feedback form plugin

A Koha plugin that adds user feedback functionality to Koha’s OPAC.

What is the ‘AskALibrarian’ Koha plugin?

It is a Koha plugin that adds a modal user feedback form to the Koha OPAC. It is written to utility the Koha Plugin System that was originally introduced into #kohails with version 3.12. This means that while the feature is an extension to a stock Koha installation, it is essentially a koha-native solution. Thus it is well-integrated within Koha as compared to any other third party solution. In terms of direct advantages it brings in (a) ease of maintainability across Koha upgrades, (b) ability to use the submitted data directly from Koha’s SQL reports, (c) data privacy – the data is stored directly inside your Koha database, as opposed to with any other 3rd party solution (something that assumes far greater significance in the GDPR era).

Why this plugin?

The Koha OPAC provides a lot of functionality to both the library staff as well as the library patrons. Below is a short list of things you can (there are more) and things you can not do.

Things you can ? Things you can’t ?
  • Login with your user account
  • Reserve a book
  • Renew a book
  • Pay a fine or fee
  • Update your contact information
  • Do a self-registration
  • Submit a purchase suggestion
  • Add star ratings
  • And much more
  • Leave a feedback for the library staff

Since a lot of L2C2 Technologies’s client partners seem to be wanting the facility of user feedback forms, we finally decided “Why not… let’s do a plugin!” And so the AskALibrarian plugin was born.

How does it work?

The plugin adds a bootstrap modal feedback form as a menu option on the navbar at the top of the Koha OPAC. On submission of the form by the user / visitor, the information is submitted via an AJAX call to a Perl script – askalibrarian.pl, on the staff client side. The script invokes the required sub-routines from the plugin to do two things : (a) send the user an acknowledgement of the submitted input to the user’s email address, it provided is reachable and (b) store the submitted data in the koha_plugin_com_l2c2technologies_askalibrarian_feedback table in the Koha database. A callback sends up an alert popup on the OPAC, informing if it has successfully captured the data.

How to get the plugin?

The plugin is published under GNU GPL v3.0 license and is available here from L2C2 Technologies‘s GitHub repository. Pull requests for bugs or improvements are welcome 🙂

Please show me step by step!

Given how our readers from the Indian sub-continent are fond of “step-by-step” instructions, we have a small video for our readers (about 11 mins) that shows how to setup and use plugin.

Enjoy! May the source be with you!

Koha Patron Image Packer helper script

One-click utility to help build bulk patron image loader zip archive for users accessing Koha ILS from their Windows PCs.

Academic libraries like the ones in colleges, typically have a need to bulk upload patron images (of students) at the start of every school year. The photos are usually made available from their admissions office, named and numbered as per either unique enrollment id or student id of each student. The college libraries typically also utilize these same numbers as their library card numbers.

Of course, when several hundred patron images have to be imported, Koha’s bulk patron image upload option comes in very handy. It is available at More > Tools > Patrons and Circulation > Upload Patron Images. We can create a ZIP archive with all these uniquely named and numbered photos along with a manifest file named either DATALINK.txt or IDLINK.txt. The structure of the manifest file is simple – <cardnumber><separator><filename>. The <separator> can be a comma or a tab character.

The only kink in this work flow is that quite often we would see people creating that manifest by hand. This, as expected, quite often led to errors, and as a result they often had to make multiple runs at uploading the photos along with wasting precious time identifying the errors in the manifest.

So when our client-partner Basanti Devi College Library wanted to upload several hundred patron images at one go, we decided to put together a small PowerShell script that could automate this function so that it could get done quickly, without any error and at the click of the mouse.

The Koha Patron Image Packer is the outcome. It is small PowerShell script that allows users working on Windows based system to build their bulk patron image batch loader zip file along with it’s IDLINK.txt manifest with just a single click. It’s minimum requirements are PowerShell v 3.0 script with .NET Framework 4.0.

Get the code

The code is available from https://gitlab.com/indradg/koha-patron-image-packer

Installation

Installation is nothing more than copying the datalinker.ps1 file over to folder which is holding your patron images named as per their cardnumbers in Koha.

However, before your Windows system may allow you to run an PowerShell script, it may be require you to set your ExecutionPolicy to RemoteSigned for your CurrentUser. To do that, go to Run and type in PowerShell and hit enter to open up the Windows PowerShell interactive console and type in the following command:

Set-ExecutionPolicy -Scope CurrentUser -ExecutionPolicy RemoteSigned

To check if this has been set currently you can run the command and check the output by typing in

Get-ExecutionPolicy -List

Demostration

A screencast of this feature at work is available on Youtube. It is a short video under 2 minutes. Watch it at 720p at full-screen if supported on your bandwidth.

License

It is released under GNU GPL v3 or later, the same license as Koha.

Acknowledgment

A.J. Tomson, Librarian, Devagiri College, Kozhikode who wrote an early version of analogous script in Python in Koha 3.12 days.

Vimal Kumar V. whose blog post “A useful script to compress patron images to upload” had originally put the spotlight on Mr. Tomson’s work.

Generate a single sheet custom MARC21 framework in 2 minutes

For intermediate Koha ILS users who wish to quickly generate a single tab MARC framework.

Last Thursday, Ashish Kumar Barik, librarian at our new client-partner Midnapore City College filed a support ticket asking for a custom single sheet MARC21 framework or what is more commonly referred to by LIS professionals as a “worksheet“. He wrote that he wanted the following tags 000, 003, 005, 008, 020, 040, 041, 044, 082, 100, 245, 250, 260, 300, 440, 490, 500, 504, 650, 700, 942 and that the sub-tags/fields should be set as in the default marc framework shipped with Koha. We promised him his new framework. Being new to this side of Koha, he of course had missed out two key fields without which his system would be rendered practically useless i.e. the two local use tags952 and 999. Koha uses 952 to handle holdings (item) information and 999 is purely an internal tag used to track the bibliographic records.

Now anyone who has ever setup a new MARC framework knows that it can be a laborious and time consuming task. Further, there are chances of introducing inadvertent human errors that may lead to error or bad data when used as a part of the framework. As a result, at L2C2 Technologies we have developed several well defined strategies to manage custom marc frameworks for our clients. In today’s blog, we are going to share the simplest of the techniques we use in cases like this. The outcome of this exercise is a 100% error free marc framework generated in less than 2 minutes.

LEGAL DISCLAIMER: The next steps involve directly accessing and making changes in the the Koha database. So use these instructions at your own risk, if you face any data loss, corruption or system errors we are not responsible.

The Steps

  1. We used a regex capable editor like Notepad++ to quote the fields mentioned by Ashish, so that 000, 003, 005, 008, 020, 040, 041, 044, 082, 100, 245, 250, 260, 300, 440, 490, 500, 504, 650, 700, 942 became ‘000’, ‘003’, ‘005’, ‘008’, ‘020’, ‘040’, ‘041’, ‘044’, ‘082’, ‘100’, ‘245’, ‘250’, ‘260’, ‘300’, ‘440’, ‘490’, ‘500’, ‘504’, ‘650’, ‘700’, ‘942’. And while we did that, we also added the following fields missing in his list i.e. ‘952’, ‘999’.
  2. Next we defined a new framework MCC1 (MCC Framework) by visiting Home -> Administration -> MARC bibliographic framework -> New Framework
  3. Next we copied the default framework into MCC1 as its base, since that is what Ashish had wanted. At this point, the MCC1 framework is exactly same as the default framework of Koha.
  4. Next we fired up the MySQL console and logged in with the user id and passwd from MCC’s koha-conf.xml, and chose Ashish’s database in this case koha_mcc for the next steps.
  5. Fired the following SQL query :
    UPDATE
       `marc_subfield_structure` 
    SET
       tab=0
    WHERE 
       `frameworkcode`='MCC1' 
    AND 
       `tagfield` IN ('000', '003', '005', '008', '020', '040', '041', '044', '082', '100', '245', '250', '260', '300', '440', '490', '500', '504', '650', '700', '942')
    AND
       `tab`!=0;

    MySQL client told us 152 rows were affected.

    EXPLANATION: This moved all 1XX to 9XX (except 952 and 999) marc fields into Tab 0. The images below help illustrate the condition after this step:

  6. The next step was to set the rest of the fields outside the list supplied by Ashish *plus* 952 and 999 to be ‘ignored’ by Koha when using the MCC1 framework. And thus the following SQL query:
    UPDATE 
        `marc_subfield_structure` 
    SET 
        `tab`='-1' 
    WHERE
        `frameworkcode`='MCC1'
    AND 
        `tagfield` NOT IN ('000', '003', '005', '008', '020', '040', '041', '044', '082', '100', '245', '250', '260', '300', '440', '490', '500', '504', '650', '700', '942', '952', '999') 
    AND
        `tab`!=0;

    This time MySQL reported that 3416 rows were updated.

  7. Our last step at the MySQL command line was the following query that removed the unwanted 0XX fields from Tab 0 :
    UPDATE 
        `marc_subfield_structure` 
    SET 
        `tab`='-1' 
    WHERE
        `frameworkcode`='MCC1'
    AND 
        `tagfield` NOT IN ('000', '003', '005', '008', '020', '040', '041', '044', '082', '100', '245', '250', '260', '300', '440', '490', '500', '504', '650', '700', '942', '952', '999');

    MySQL reported 341 rows were affected.

  8. Coming back to MCC’s Koha staff client, we did the most important thing i.e. running MARC Bibliographic framework test. The test came out clean without any error.
  9. That’s it! MCC’s custom MARC framework is ready for use. Click on the image below and then zoom in to see the details up close.

NECOPAC : a new z39.50 service from North Eastern India

The launch of NECOPAC the first volunteer-run, freely available, public z39.50 service in North Eastern India.

On the auspicious occasion of Rongali Bihu (for the Assamese) and Poila Boishakh (for the Bengali), on behalf of the NECOPAC team, I’m happy to announce the start of NECOPAC z39.50 service. This is the first freely available, public z39.50 (copy cataloging) service in North Eastern India. As on date there are 92,333 bibliographic records in the database, all of which are volunteer contributed. We are expecting more records to be contributed soon.

Origin of the project

The germ of the idea of NECOPAC started about 2 years back during a chance meeting of a group of young like-minded library professionals and technology specialists in Guwahati, Assam.

The north eastern Indian is home to 8 states – Assam, Manipur, Tripura, Meghalaya, Mizoram, Nagaland, Arunachal Pradesh and Sikkim. The region boasts of great cultural heritage and diversityr. Libraries are an important means of preserving and disseminating this rich heritage, traditional knowledge, literature and other creative output.

Freely available copy cataloging of Indian publications using z39.50 service, to this day, remains largely a distant dream for most Indian library professionals. The scenario in the North East is even more difficult when it comes to publications in the local languages from this part of India.

The NECOPAC z39.50 service is a volunteer-run collaborative attempt at bridging this service gap. It is the first freely available, public z39.50 service in the entire North Eastern India. For us to grow bigger and be able to serve more LIS professionals in the NE, we need your active support and contributions i.e. a copy of your bibliographic records.

DISCLAIMER : The bibliographic records are provided on AS-IS basis by this service and the NECOPAC team does not vouch for the correctness or accuracy of these records.

Connecting and downloading records from NECOPAC

You will need to setup your z39.50 client using these details:

Parameter Setting
Server name NECOPAC
Hostname z3950.necopac.in
Port 9999
Database biblios
Syntax MARC21 / USMARC
Encoding UTF-8