Holdings, comprised of call numbers, items, and parts, are the set of objects that enable users to locate and potentially acquire materials from your library system.
Call numbers connect libraries to bibliographic records. Each call number has a label associated with a classification scheme such as a the Library of Congress or Dewey Decimal systems, and can optionally have either or both a label prefix and a label suffix. Label prefixes and suffixes do not affect the sort order of the label.
Copies connect call numbers to particular instances of that resource at a particular library. Each item has a barcode and must exist in a particular item location. Other optional attributes of items include circulation modifier, which may affect whether that item can circulate or for how long it can circulate, and OPAC visibility, which controls whether that particular item should be visible in the public catalog.
Parts provide more granularity for items, primarily to enable patrons to place holds on individual parts of a set of items. For example, an encyclopedia might be represented by a single bibliographic record, with a single call number representing the label for that encyclopedia at a given library, with 26 items representing each letter of the alphabet, with each item mapped to a different part such as A, B, C, … Z.
To migrate this data into your Evergreen system, you will create another staging table in the database to hold the raw data for your materials from which the actual call numbers, items, and parts will be generated.
Begin by connecting to the PostgreSQL database using the psql command. For example:
psql -U <user-name> -h <hostname> -d <database>
Create the staging materials table by issuing the following SQL statement:
CREATE TABLE staging_materials ( bibkey BIGINT, -- biblio.record_entry_id callnum TEXT, -- call number label callnum_prefix TEXT, -- call number prefix callnum_suffix TEXT, -- call number suffix callnum_class TEXT, -- classification scheme create_date DATE, location TEXT, -- shelving location code item_type TEXT, -- circulation modifier code owning_lib TEXT, -- org unit code barcode TEXT, -- copy barcode part TEXT );
For the purposes of this example migration of call numbers, items, and parts, we assume that you are able to create a tab-delimited file containing values that map to the staging table properties, with one item per line. For example, the following 5 lines demonstrate how the file could look for 5 different items, with non-applicable attribute values represented by \N, and 3 of the items connected to a single call number and bibliographic record via parts:
1 QA 76.76 A3 \N \N LC 2012-12-05 STACKS BOOK BR1 30007001122620 \N 2 GV 161 V8 Ref. Juv. LC 2010-11-11 KIDS DVD BR2 30007005197073 \N 3 AE 5 E363 1984 \N \N LC 1984-01-10 REFERENCE BOOK BR1 30007006853385 A 3 AE 5 E363 1984 \N \N LC 1984-01-10 REFERENCE BOOK BR1 30007006853393 B 3 AE 5 E363 1984 \N \N LC 1984-01-10 REFERENCE BOOK BR1 30007006853344 C
Once your holdings are in a tab-delimited format—which, for the purposes of this example, we will name holdings.tsv--you can import the holdings file into your staging table. Copy the contents of the holdings file into the staging table using the COPY SQL statement:
COPY staging_items (bibkey, callnum, callnum_prefix, callnum_suffix, callnum_class, create_date, location, item_type, owning_lib, barcode, part) FROM 'holdings.tsv';
Generate the item locations you need to represent your holdings:
INSERT INTO asset.copy_location (name, owning_lib)
SELECT DISTINCT location, 1 FROM staging_materials
WHERE NOT EXISTS (
SELECT 1 FROM asset.copy_location
WHERE name = location
);Generate the circulation modifiers you need to represent your holdings:
INSERT INTO config.circ_modifier (code, name, description, sip2_media_type)
SELECT DISTINCT circmod, circmod, circmod, '001'
FROM staging_materials
WHERE NOT EXISTS (
SELECT 1 FROM config.circ_modifier
WHERE circmod = code
);Generate the call number prefixes and suffixes you need to represent your holdings:
INSERT INTO asset.call_number_prefix (owning_lib, label)
SELECT DISTINCT aou.id, callnum_prefix
FROM staging_materials sm
INNER JOIN actor.org_unit aou
ON aou.shortname = sm.owning_lib
WHERE NOT EXISTS (
SELECT 1 FROM asset.call_number_prefix acnp
WHERE callnum_prefix = acnp.label
AND aou.id = acnp.owning_lib
) AND callnum_prefix IS NOT NULL;
INSERT INTO asset.call_number_suffix (owning_lib, label)
SELECT DISTINCT aou.id, callnum_suffix
FROM staging_materials sm
INNER JOIN actor.org_unit aou
ON aou.shortname = sm.owning_lib
WHERE NOT EXISTS (
SELECT 1 FROM asset.call_number_suffix acns
WHERE callnum_suffix = acns.label
AND aou.id = acns.owning_lib
) AND callnum_suffix IS NOT NULL;Generate the call numbers for your holdings:
INSERT INTO asset.call_number (
creator, editor, record, owning_lib, label, prefix, suffix, label_class
)
SELECT DISTINCT 1, 1, bibkey, aou.id, callnum, acnp.id, acns.id,
CASE WHEN callnum_class = 'LC' THEN 1
WHEN callnum_class = 'DEWEY' THEN 2
END
FROM staging_materials sm
INNER JOIN actor.org_unit aou
ON aou.shortname = owning_lib
INNER JOIN asset.call_number_prefix acnp
ON COALESCE(acnp.label, '') = COALESCE(callnum_prefix, '')
INNER JOIN asset.call_number_suffix acns
ON COALESCE(acns.label, '') = COALESCE(callnum_suffix, '')
;Generate the items for your holdings:
INSERT INTO asset.copy (
circ_lib, creator, editor, call_number, location,
loan_duration, fine_level, barcode
)
SELECT DISTINCT aou.id, 1, 1, acn.id, acl.id, 2, 2, barcode
FROM staging_materials sm
INNER JOIN actor.org_unit aou
ON aou.shortname = sm.owning_lib
INNER JOIN asset.copy_location acl
ON acl.name = sm.location
INNER JOIN asset.call_number acn
ON acn.label = sm.callnum
WHERE acn.deleted IS FALSE
;Generate the parts for your holdings. First, create the set of parts that are required for each record based on your staging materials table:
INSERT INTO biblio.monograph_part (record, label)
SELECT DISTINCT bibkey, part
FROM staging_materials sm
WHERE part IS NOT NULL AND NOT EXISTS (
SELECT 1 FROM biblio.monograph_part bmp
WHERE sm.part = bmp.label
AND sm.bibkey = bmp.record
);Now map the parts for each record to the specific items that you added:
INSERT INTO asset.copy_part_map (target_copy, part)
SELECT DISTINCT acp.id, bmp.id
FROM staging_materials sm
INNER JOIN asset.copy acp
ON acp.barcode = sm.barcode
INNER JOIN biblio.monograph_part bmp
ON bmp.record = sm.bibkey
WHERE part IS NOT NULL
AND part = bmp.label
AND acp.deleted IS FALSE
AND NOT EXISTS (
SELECT 1 FROM asset.copy_part_map
WHERE target_copy = acp.id
AND part = bmp.id
);At this point, you have loaded your bibliographic records, call numbers, call number prefixes and suffixes, items, and parts, and your records should be visible to searches in the public catalog within the appropriate organization unit scope.