...
Table of Contents | ||
---|---|---|
|
Page Tree | ||||
---|---|---|---|---|
|
Collection Objects extract
...
TMS table name | TMS field name | CSpace field name | notes | ||||||||
---|---|---|---|---|---|---|---|---|---|---|---|
Objects | ObjectID | shortIdentifier pahmaObjectID |
| ||||||||
Components ObjComponents | ComponentID | shortIdentifier pahmaObjectID | must ensure no duplicates with Objects.ObjectID | ||||||||
Objects | ObjectNumber | objectNumber |
| ||||||||
Components ObjComponents | ComponentNumber | objectNumber |
| ||||||||
Objects | 'no' | isComponent |
| ||||||||
ObjComponents | 'yes' | isComponent |
| ||||||||
Objects | CatRais | pahmaCollection | NEW field (repeating; controlled list) | ||||||||
Objects | DepartmentID | pahmaTmsLegacyDepartment | FK to Departments; NEW field (controlled list) | ||||||||
Objects | HistAttributions | objectHistoryNote |
| ||||||||
Objects | LoanClass | pahmaTms2003DataSource | NEW field (controlled list) | ||||||||
Objects | Markings | distinguishingFeatures |
| ||||||||
Objects | Medium | material |
| ||||||||
Objects | MTB_PlaceTermID ObjectStatusID | fieldCollectionPlace | reference to Place Authority pahmaObjectStatus | 6/12/2012: deprecated. Object Status becoming a repeating field. | |||||||
Objects | Notes ObjectTypeID | comments collection | FK to ObjectTypes | ||||||||
Objects | ObjectStatusID | pahmaObjectStatus | FK to ObjectStatuses; NEW field (controlled list) | ||||||||
Objects | ObjectTypeID | collection | FK to ObjectTypes | ||||||||
Objects | PaperFileRef PaperFileRef | nagpraInventoryName | FK to MTB_NagpraInvNames; controlled list | ||||||||
Objects | Portfolio | portfolioSeries | FK to MTB_PortfolioSeries; NEW field (controlled list) | Objects | Provenance | fieldLocVerbatim |
| ||||
Objects | MTB_ResponsibleDept | responsibleDepartment | controlled list | ||||||||
Objects | Signed State | inscriptionContent pahmaNagpraCodeLegacy | FK to MTB_NagpraBurialCodes | Objects | State | pahmaNagpraCodeLegacy | ; controlled list | Objects | Title | title |
|
ObjContext | Integer3 | inventoryCount | NEW field |
sql query
view: cs_objects (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, o.ObjectNumber objectNumber, NULL'no' isComponent, o.CatRais pahmaCollection, d.Department pahmaTmsLegacyDepartment, o.HistAttributions objectHistoryNote, (CASE WHEN lower(o.LoanClass) not in ('', 'catalog card', 'inventory', 'ledger') THEN o.LoanClass END) pahmaTms2003DataSource, o.Markings distinguishingFeatures, o.Medium material, MTB_PlaceTermID fieldCollectionPlace, Notes comments, s.ObjectStatus pahmaObjectStatus, t.ObjectType collection, i.CSpaceID nagpraInventoryName, o.MTB_Portfolio portfolioSeries, Provenance(CASE fieldLocVerbatim,WHEN o.MTB_ResponsibleDept responsibleDepartment,= 1 SignedTHEN inscriptionContent,'Natasha Johnson' b.optionID pahmaNagpraCodeLegacy, Title title, c.integer3 inventoryCount FROM Objects o LEFT OUTER JOIN Departments d ON o.departmentID = d.departmentID LEFT OUTER JOIN ObjectStatuses s ON o.objectStatusID = s.objectStatusID LEFT OUTER JOIN ObjectTypes t ON o.objectTypeID = t.objectTypeID LEFT OUTER JOIN MTB_NagpraInvNames i ON o.paperFileRef = i.LongTMSname LEFT OUTER JOIN MTB_NagpraBurialCodes b ON o.state = b.codeWHEN o.MTB_ResponsibleDept = 2 THEN 'Leslie Freund' WHEN o.MTB_ResponsibleDept = 3 THEN 'Victoria Bradshaw' WHEN o.MTB_ResponsibleDept = 4 THEN 'Alicja Egbert' WHEN o.MTB_ResponsibleDept = 5 THEN 'No collection manager (Registration)' WHEN o.MTB_ResponsibleDept = 8 THEN 'uncertain' END) responsibleDepartment, b.optionID pahmaNagpraCodeLegacy, c.integer3 inventoryCount FROM Objects o LEFT OUTER JOIN ObjContextDepartments cd ON o.objectIDdepartmentID = cd.objectIDdepartmentID WHERELEFT OUTER o.IsVirtualJOIN =ObjectStatuses 0s ANDON o.IsTemplateobjectStatusID = s.objectStatusID 0 UNIONLEFT ALLOUTER SELECTJOIN ObjectTypes 'c't +ON CAST(co.componentIDobjectTypeID AS VARCHAR) objectID, c.componentNumber objectNumber, 'Component' isComponent, NULL pahmaCollection, NULL pahmaTmsLegacyDepartment, NULL objectHistoryNote, NULL pahmaTms2003DataSource, NULL distinguishingFeatures, NULL material, NULL fieldCollectionPlace, NULL comments, NULL pahmaObjectStatus, NULL collection, NULL nagpraInventoryName, NULL portfolioSeries, NULL fieldLocVerbatim, NULL responsibleDepartment, NULL inscriptionContent, NULL pahmaNagpraCodeLegacy, NULL title, NULL inventoryCount FROM ObjComponents c WHERE c.objectID = t.objectTypeID LEFT OUTER JOIN MTB_NagpraInvNames i ON o.paperFileRef = i.LongTMSname LEFT OUTER JOIN MTB_NagpraBurialCodes b ON o.state = b.code LEFT OUTER JOIN ObjContext c ON o.objectID = c.objectID WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.componentNumber objectNumber, 'yes' isComponent, NULL pahmaCollection, NULL pahmaTmsLegacyDepartment, NULL objectHistoryNote, NULL pahmaTms2003DataSource, NULL distinguishingFeatures, NULL material, NULL pahmaObjectStatus, NULL collection, NULL nagpraInventoryName, NULL portfolioSeries, NULL responsibleDepartment, NULL pahmaNagpraCodeLegacy, NULL inventoryCount FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) ; |
...
- object components are included as first-class objects if and only if there are multiple components for parent object
- object components must should have componentID (objectID) that does not conflict with any parent objectID: we can prepend "c" to the componentID to ensure this, per Michael (1/12/12)
- many object components have a non-unique componentNumber (objectNumber), duplicated by other components and/or parent object; these values are OK to import as-is, per Michael (1/12/12)
- "componentType" field does not need to be imported, per Michael (1/12/12)
- "inscribed" field has only a few entries, which can be updated manually after data migration, per Michael (12/15/11)
- "dimensions" field will be handled by a separate extract (John Lowe is working on this as of 1/9/12)
- DONE: add 6 new custom fields: pahmaCollection, objectStatus, pahmaTms2003DataSource, pahmaTmsLegacyDepartment, inventoryCount, portfolioSeries
- DONE: add controlled list options for 5 of these new fields (all except inventoryCount)
- DONE: nagpraInventoryName field values need to be transformed to match option ID values in existing controlled list
- TODO: "dimensions" field still needs to be dealt with (John Lowe is working on this as of 1/9/12)
- TODODONE: add isComponent field for indicating components; field should be hidden in main part of UI but included in display name at the top
- TODO: update options for responsibleDepartment field
Object-Object Relationships extract
sql query
view:
...
- June 12, 2012: Inventory Count now coming from two fields.
- June 12, 2012: Object Status now a repeating field so not using pahmaObjectStatus in this view
Object-Object Relationships extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjComponents | ObjectID | reference to one Object |
|
ObjComponents | ComponentID | reference to other Object |
|
Associations | ID1 | reference to one Object |
|
Associations | ID2 | reference to other Object |
|
sql query
view: cs_objectobjectrelationships (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(c.objectID AS VARCHAR) objectID_1, 'c' + CAST(c.componentID AS VARCHAR) objectID_2, 'Object-Component' relationshipType FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) UNION ALL SELECT ; |
notes
- this should be imported as two-way relationship, so it shows up in UI for both parent and child object
Number of Objects extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | ObjectCount | numberOfObjects |
|
Components | CompCount | numberOfObjects |
|
sql query
view:
Code Block | ||
---|---|---|
sql | sql | SELECT o.objectID, o.objectCount numberOfObjects FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND o.objectID NOT IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) UNION ALL SELECT o.objectID, (CASE WHEN c.compCount > o.objectCount THEN c.compCount ELSE o.objectCount END) numberOfObjects FROM Objects o JOIN ObjComponents c ON o.objectID = c.objectID WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.compCount numberOfObjects FROM ObjComponents c WHERE c.objectID CAST(oa.ID1 AS VARCHAR) objectID_1, CAST(oa.ID2 AS VARCHAR) objectID_2, r.relation1 + '-' + r.relation2 relationshipType FROM Associations oa, Objects obj1, Objects obj2, Relationships r WHERE oa.tableID = 108 AND oa.ID1 = obj1.objectID AND oa.ID2 = obj2.objectID AND obj1.IsVirtual = 0 AND obj1.IsTemplate = 0 AND obj2.IsVirtual = 0 AND obj2.IsTemplate = 0 AND oa.relationshipID = r.relationshipID ; |
notes
- this should be imported as two-way relationship, so it shows up in UI for both objects
- relationship type is included in this query, but we don't have a good place to put it in CSpace
Number of Objects extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | ObjectCount | numberOfObjects |
|
ObjComponents | CompCount | numberOfObjects |
|
sql query
view: cs_numberofobjects (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, o.objectCount numberOfObjects FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND o.objectID NOT IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) >= 1) ; |
notes
- for objects with single component, componentCount should be used in lieu of objectCount if and only if it is greater than objectCount, per Michael (1/5/12)
Alternate Numbers extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
AltNums | AltNum | pahmaAltNum |
|
Components | ComponentNumber | pahmaAltNum |
|
AltNums | Description | pahmaAltNumType | controlled list |
AltNums | Remarks | pahmaAltNumNote |
|
sql query
view: cs_alternatenumbers
...
SELECT
n.ID objectID,
n.altnum pahmaAltNum,
n.description pahmaAltNumType,
n.remarks pahmaAltNumNote
FROM
AltNums n
WHERE
n.tableID = 108
UNION ALL
SELECT
c.objectID,
c.componentNumber pahmaAltNum,
NULL pahmaAltNumType,
NULL pahmaAltNumNote
FROM
ObjComponents c
JOIN Objects o ON c.objectID = o.objectID
WHERE
o.IsVirtual = 0 AND o.IsTemplate = 0
AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1)
AND c.componentNumber IS NOT NULL
AND c.componentNumber != o.objectNumber
;
notes
- DONE: 3 new custom fields in repeating field group
- DONE: add controlled list options for pahmaAltNumType field
...
UNION ALL
SELECT
CAST(o.objectID AS VARCHAR) objectID,
(CASE WHEN c.compCount > o.objectCount THEN c.compCount ELSE o.objectCount END) numberOfObjects
FROM
Objects o
JOIN ObjComponents c ON o.objectID = c.objectID
WHERE
o.IsVirtual = 0 AND o.IsTemplate = 0
AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1)
UNION ALL
SELECT
'c' + CAST(c.componentID AS VARCHAR) objectID,
c.compCount numberOfObjects
FROM
ObjComponents c
WHERE
c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1)
;
|
notes
- for objects with single component, componentCount should be used in lieu of objectCount if and only if it is greater than objectCount, per Michael (1/5/12)
Alternate Numbers extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects AltNums | ObjectName AltNum | objectName pahmaAltNum |
|
Components ObjComponents | ComponentName ComponentNumber | objectName pahmaAltNum |
|
ObjectNames AltNums | ObjectName Description | objectName pahmaAltNumType |
|
ObjectNames | LanguageID | objectNameLanguage | FK to Languages |
ObjectNames | ObjectNameTypeID | objectNameNote | FK to ObjectNameTypes; concatenate with Remarks |
ObjectNames | Remarks | objectNameNote | concatenate with ObjectNameType |
controlled list | |||
AltNums | Remarks | pahmaAltNumNote |
|
sql query
view: cs_objectnamesalternatenumbers (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT o.CAST(n.ID AS VARCHAR) objectID, o.objectName n.altnum pahmaAltNum, NULL objectNameLanguage n.description pahmaAltNumType, NULL objectNameNoten.remarks pahmaAltNumNote FROM ObjectsAltNums on WHERE o n.IsVirtualtableID = 108 0 AND on.IsTemplatealtnum IS =NOT 0NULL UNION ALL SELECT 'c' + CAST(c.componentIDobjectID AS VARCHAR) objectID, c.componentNamecomponentNumber objectNamepahmaAltNum, NULL objectNameLanguagepahmaAltNumType, NULL objectNameNotepahmaAltNumNote FROM ObjComponents c WHEREJOIN Objects o ON c.objectID IN (SELECT t= o.objectID FROMWHERE ObjComponents to.IsVirtual GROUP= BY t0 AND o.IsTemplate = 0 AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) >= 1) AND c.componentNamecomponentNumber IS NOT NULL UNION ALL SELECT AND c.objectID,componentNumber != co.componentNameobjectNumber objectName, NULL objectNameLanguage, 'Component name' objectNameNote FROM ObjComponents c JOIN Objects o ON c.objectID = o.objectID ; |
notes
- DONE: 3 new custom fields in repeating field group
- DONE: add controlled list options for pahmaAltNumType field
Object Names extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | ObjectName | objectName |
|
ObjComponents | ComponentName | objectName |
|
ObjectNames | ObjectName | objectName |
|
ObjectNames | LanguageID | objectNameLanguage | FK to Languages |
ObjectNames | ObjectNameTypeID | objectNameNote | FK to ObjectNameTypes; concatenate with Remarks |
ObjectNames | Remarks | objectNameNote | concatenate with ObjectNameType |
sql query
view: cs_objectnames (refreshed 2012-03-22)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, o.objectName, NULL objectNameLanguage, NULL objectNameNote FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND co.objectIDobjectName IS INNOT (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) AND NULL UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.componentName ISobjectName, NOT NULL objectNameLanguage, AND coalesce(o.objectName,'') != c.componentName UNION ALL SELECT n.objectID, n.objectName, (CASE WHEN n.languageID != '0' THEN l.MTB_ISOcode END) objectNameLanguage, (CASE WHEN n.objectNameTypeID != '0' THEN t.objectNameType ELSE '' END) + (CASE WHEN n.objectNameTypeID != '0' AND n.remarks is not null THEN '; ' ELSE '' END) + coalesce(n.remarks, '') NULL objectNameNote FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) AND c.componentName IS NOT NULL UNION ALL SELECT CAST(c.objectID AS VARCHAR) objectID, c.componentName objectName, NULL objectNameLanguage, 'Component name' objectNameNote FROM objectNames n LEFT OUTERObjComponents c JOIN objectNameTypesObjects to ON nc.objectNameTypeIDobjectID = to.objectNameTypeIDobjectID WHERE LEFT OUTERo.IsVirtual JOIN= languages0 lAND ON no.languageIDIsTemplate = l.languageID WHERE n.objectName0 AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) AND c.componentName IS NOT NULL ; |
notes
- TODO: change objectNameLanguage from static term list to vocabulary-controlled list
- TODO: add this option to languages list: <option id="gre">Modern Greek</option>
Brief Descriptions extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | description | briefDescription |
|
Components | physDesc | briefDescription |
|
sql query
view:
Code Block | ||
---|---|---|
sql | sql | SELECT o.objectID, o.description briefDescription FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.physDesc briefDescription FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) AND c.physDesc IS NOT NULL UNION ALL SELECT c.objectID, c.physDesc briefDescription FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) AND c.physDesc AND coalesce(o.objectName,'') != c.componentName UNION ALL SELECT CAST(n.objectID AS VARCHAR) objectID, n.objectName, (CASE WHEN n.languageID != '0' THEN 'urn:cspace:pahma.cspace.berkeley.edu:vocabularies:name(languages):item:name(' + rtrim(l.MTB_ISOcode) + ')''' + (CASE WHEN charindex('/', l.language) > 0 THEN substring(l.language, 1, charindex('/', l.language) - 1) ELSE l.language END) + '''' END) objectNameLanguage, (CASE WHEN n.objectNameTypeID != '0' THEN t.objectNameType ELSE '' END) + (CASE WHEN n.objectNameTypeID != '0' AND n.remarks is not null THEN '; ' ELSE '' END) + coalesce(n.remarks, '') objectNameNote FROM objectNames n LEFT OUTER JOIN objectNameTypes t ON n.objectNameTypeID = t.objectNameTypeID LEFT OUTER JOIN languages l ON n.languageID = l.languageID WHERE n.objectName IS NOT NULL ; |
Object Titles extract
...
notes
- DONE: change objectNameLanguage from static term list to vocabulary-controlled list
Brief Descriptions extract
field mapping
TMS table name | TMS field name | CSpace field name | notes | |
---|---|---|---|---|
ObjTitles Objects | Title description | title briefDescription |
| |
ObjTitles ObjComponents | LanguageID physDesc | titleLanguage briefDescription | FK to Languages | |
ObjTitles TextEntries | TitleTypeID textEntry | titleNote | FK to TitleTypes briefDescription | where textTypeID is 6, 7, or 23 |
sql query
view: cs_objecttitlesbriefdescriptions (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID, AS title,VARCHAR) objectID, (CASE WHEN no.languageIDdescription != '0' THEN l.MTB_ISOcode END) titleLanguage, (CASE WHEN n.titleTypeID != '0' THEN t.titleType END) titleType FROM objTitles n LEFT OUTER JOIN titleTypes t ON n.titleTypeID = t.titleTypeID LEFT OUTER JOIN languages l ON n.languageID = l.languageID ; |
notes
- "remarks" field has only a few entries, which can be updated manually after data migration, per Michael (12/15/11)
- TODO: change titleLanguage from static term list to vocabulary-controlled list
- TODO: update options for titleType field
Associated Dates extract
this data cannot be imported until v2.1
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjDates | EventType | assocDateType |
|
ObjDates | DateText | assocDate_dateDisplayDate |
|
ObjDates | DateBegSearch | assocDate_dateEarliestSingleYear |
|
ObjDates | DateEndSearch | assocDate_dateLatestYear |
|
ObjDates | DayBegSearch | assocDate_dateEarliestSingleDay |
|
ObjDates | DayEndSearch | assocDate_dateLatestDay |
|
ObjDates | MonthBegSearch | assocDate_dateEarliestSingleMonth |
|
ObjDates | MonthEndSearch | assocDate_dateLatestMonth |
|
ObjDates | Remarks | assocDateNote |
|
sql query
view: cs_associateddates
...
SELECT
objectID,
lower(eventType) assocDateType,
dateText assocDate_dateDisplayDate,
(CASE WHEN dateBegSearch != '0' THEN dateBegSearch END) assocDate_dateEarliestSingleYear,
(CASE WHEN dateEndSearch != '0' THEN dateEndSearch END) assocDate_dateLatestYear,
dayBegSearch assocDate_dateEarliestSingleDay,
dayEndSearch assocDate_dateLatestDay,
monthBegSearch assocDate_dateEarliestSingleMonth,
monthEndSearch assocDate_dateLatestMonth,
remarks assocDateNote
FROM
ObjDates
WHERE
lower(eventType) not in ('', 'accessioned', 'date collected', 'secondary collection date', 'tertiary collection date', 'date made')
AND (dateText is not null OR dateBegSearch != 0)
;
notes
- DONE: populate controlled list options for assocDateType field
- TODO: wait until assocDate field is changed into a structured date (in v2.1; see CSPACE-4775)
Field Collection Dates extract
this data cannot be imported until v2.1
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjDates | DateText | fieldCollectionDate_dateDisplayDate |
|
ObjDates | DateBegSearch | fieldCollectionDate_dateEarliestSingleYear |
|
ObjDates | DateEndSearch | fieldCollectionDate_dateLatestYear |
|
ObjDates | DayBegSearch | fieldCollectionDate_dateEarliestSingleDay |
|
ObjDates | DayEndSearch | fieldCollectionDate_dateLatestDay |
|
ObjDates | MonthBegSearch | fieldCollectionDate_dateEarliestSingleMonth |
|
ObjDates | MonthEndSearch | fieldCollectionDate_dateLatestMonth |
|
ObjDates | Remarks | fieldCollectionNote |
|
Objects | Dated | fieldCollectionDate_dateDisplayDate |
|
Objects | DateBegin | fieldCollectionDate_dateEarliestSingleYear |
|
Objects | DateEnd | fieldCollectionDate_dateLatestYear |
|
sql query
view: cs_fieldcollectiondates
Code Block | ||
---|---|---|
sql | sql | SELECT objectID, dateText fieldCollectionDate_dateDisplayDate, (CASE WHEN dateBegSearch != '0' THEN dateBegSearch END) fieldCollectionDate_dateEarliestSingleYear, (CASE WHEN dateEndSearchbriefDescription FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND o.description IS NOT NULL UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.physDesc briefDescription FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) AND c.physDesc IS NOT NULL UNION ALL SELECT CAST(c.objectID AS VARCHAR) objectID, c.physDesc briefDescription FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) AND c.physDesc IS NOT NULL UNION ALL SELECT CAST(o.objectID AS VARCHAR) objectID, t.TextEntry briefDescription FROM TextEntries t JOIN Objects o ON t.ID = o.objectID JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID WHERE t.tableID = 108 AND o.IsVirtual = 0 AND o.IsTemplate = 0 AND t.TextTypeID IN (6, 7, 23) ; |
Object Titles extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | Title | title |
|
ObjTitles | Title | title |
|
ObjTitles | LanguageID | titleLanguage | FK to Languages |
ObjTitles | TitleTypeID | titleType | FK to TitleTypes |
sql query
view: cs_objecttitles (refreshed 2012-03-22)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, Title title, NULL titleLanguage, NULL titleType FROM Objects o WHERE o.IsVirtual = 0 AND o.IsTemplate = 0 AND o.title IS NOT NULL UNION ALL SELECT CAST(n.objectID AS VARCHAR) objectID, n.title, (CASE WHEN n.languageID != '0' THEN dateEndSearch END) fieldCollectionDate_dateLatestYear, dayBegSearch fieldCollectionDate_dateEarliestSingleDay, dayEndSearch fieldCollectionDate_dateLatestDay, monthBegSearch fieldCollectionDate_dateEarliestSingleMonth, monthEndSearch fieldCollectionDate_dateLatestMonth, remarks fieldCollectionNote FROM ObjDates WHERE lower(eventType) in ('date collected', 'secondary collection date', 'tertiary collection date') UNION SELECT objectID, dated fieldCollectionDate_dateDisplayDate, (CASE WHEN DateBegin != '0' THEN DateBegin END) fieldCollectionDate_dateEarliestSingleYear, (CASE WHEN DateEnd != '0' THEN DateEnd END) fieldCollectionDate_dateLatestYear, null fieldCollectionDate_dateEarliestSingleDay, null fieldCollectionDate_dateLatestDay, null fieldCollectionDate_dateEarliestSingleMonth, null fieldCollectionDate_dateLatestMonth, null fieldCollectionNote FROM Objects WHERE dated is not null OR dateBegin != '0' OR dateEnd != '0' ; |
notes
- differences in eventType ('date collected', 'secondary collection date', 'tertiary collection date') are not important and do not need to be migrated, per Michael (12/15/11)
- TODO: wait until fieldCollectionDate field is changed into a structured date (in v2.1; see CSPACE-4775)
- TODO: change fieldCollectionDate field into a repeating field
...
'urn:cspace:pahma.cspace.berkeley.edu:vocabularies:name(languages):item:name(' + rtrim(l.MTB_ISOcode) + ')''' + (CASE WHEN charindex('/', l.language) > 0 THEN substring(l.language, 1, charindex('/', l.language) - 1) ELSE l.language END) + '''' END) titleLanguage,
(CASE WHEN n.titleTypeID != '0' THEN t.titleType END) titleType
FROM
objTitles n
LEFT OUTER JOIN titleTypes t ON n.titleTypeID = t.titleTypeID
LEFT OUTER JOIN languages l ON n.languageID = l.languageID
;
|
notes
- "remarks" field has only a few entries, which can be updated manually after data migration, per Michael (12/15/11)
- DONE: change titleLanguage from static term list to vocabulary-controlled list
Ethnographic File Codes extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjUserFields | FieldValue | pahmaEthnographicFileCode |
|
sql query
view: cs_ethnographicfilecodes
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(u.objectID AS VARCHAR) objectID,
c.CSoptionID pahmaEthnographicFileCode
FROM
ObjUserFields u
JOIN MTB_EthnographicUseCodes c ON u.FieldValue = c.FieldValue
WHERE
u.FieldTypeID = 17
;
|
notes
- pahmaEthnographicFileCode is currently a static term list, but it will be changed to a Concept Authority reference once that authority is available
Comments extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjDates Objects | DateText Notes | objectProductionDate_dateDisplayDate comment |
|
ObjDates TextEntries | DateBegSearch textEntry | objectProductionDate_dateEarliestSingleYear |
|
ObjDates | DateEndSearch | objectProductionDate_dateLatestYear |
|
ObjDates | DayBegSearch | objectProductionDate_dateEarliestSingleDay |
|
ObjDates | DayEndSearch | objectProductionDate_dateLatestDay |
|
ObjDates | MonthBegSearch | objectProductionDate_dateEarliestSingleMonth |
|
ObjDates | MonthEndSearch | objectProductionDate_dateLatestMonth |
|
ObjDates | Remarks | objectProductionNote |
|
sql query
view: cs_productiondates
...
SELECT
objectID,
dateText objectProductionDate_dateDisplayDate,
(CASE WHEN dateBegSearch != '0' THEN dateBegSearch END) objectProductionDate_dateEarliestSingleYear,
(CASE WHEN dateEndSearch != '0' THEN dateEndSearch END) objectProductionDate_dateLatestYear,
dayBegSearch objectProductionDate_dateEarliestSingleDay,
dayEndSearch objectProductionDate_dateLatestDay,
monthBegSearch objectProductionDate_dateEarliestSingleMonth,
monthEndSearch objectProductionDate_dateLatestMonth,
remarks objectProductionNote
FROM
ObjDates
WHERE
lower(eventType) = 'date made'
;
notes
...
comment | where textTypeID is 27 |
sql query
view: cs_objectcomments (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
o.Notes comment
FROM
Objects o
WHERE
o.IsVirtual = 0 AND o.IsTemplate = 0
AND o.Notes IS NOT NULL
UNION ALL
SELECT
CAST(o.objectID AS VARCHAR) objectID,
t.TextEntry comment
FROM
TextEntries t
JOIN Objects o ON t.ID = o.objectID
JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID
WHERE
t.tableID = 108
AND o.IsVirtual = 0 AND o.IsTemplate = 0
AND t.TextTypeID = 27
;
|
notes
Materials note extract
field mapping
TMS table name | TMS field name | CSpace field name | notes | |||||
---|---|---|---|---|---|---|---|---|
Objects TextEntries | Bibliography textEntry | referenceNote |
| Objects | PubReferences | referenceNote | materialComponentNote | where textTypeID is 37 or 92 |
sql query
view: cs_bibliographicreferencesmaterialsnotes (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID, AS VARCHAR) bibliographyobjectID, referenceNote FROM(CASE WHEN t.textTypeID Objects= WHERE37 THEN bibliography is not null UNION ALL SELECT objectID, PubReferences referenceNote FROM Objects WHERE PubReferences is not null ; |
Annotations extract
under construction
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | Edition | annotationNote |
|
Objects | CuratorialRemarks | annotationNote |
|
Components | PrepComments | annotationNote |
|
TextEntries | ? | ? | TBD |
sql query
view: cs_annotations
...
SELECT
objectid,
edition annotationNote,
'TMS Edition field' annotationType
FROM
Objects
WHERE
edition is not null
UNION ALL
SELECT
objectid,
curatorialRemarks annotationNote,
'TMS Curatorial remarks' annotationType
FROM
Objects
WHERE
curatorialRemarks is not null
;
notes
- some annotationType field values set by query above
- TODO: include data from TextEntries table in this query
Groups extract
to be imported into the Groups Procedure schema
field mapping
...
TMS table name
...
tt.TextType + ': ' ELSE '' END) materialComponentNote_prefix,
t.TextEntry materialComponentNote
FROM
TextEntries t
JOIN Objects o ON t.ID = o.objectID
JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID
WHERE
t.tableID = 108
AND o.IsVirtual = 0 AND o.IsTemplate = 0
AND t.TextTypeID IN (37, 92)
;
|
notes
- NOTE: 'materialComponentNote_prefix' should be prepended to 'materialComponentNote' prior to import (this can't be done here because some fields are type TEXT which cannot be concatenated in SQL)
NAGPRA cultural determination extract
field mapping
TMS table name | TMS field name | CSpace field name | notes | |
---|---|---|---|---|
ObjectPackages TextEntries | ObjectPackageID textEntry | shortIdentifier |
| |
ObjectPackages | name | title |
| |
ObjectPackages | notes | scopeNote |
| |
ObjectPackages | owner | owner | FK to Users; reference to Person Authority nagpraCulturalDetermination | where textTypeID is 121 |
sql query
view: cs_groups
...
cs_nagpraculturaldeterminations (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT objectPackageID groupIDCAST(o.objectID AS VARCHAR) objectID, name titlesubstring(tt.TextType, 1, 7) notes scopeNote+ lower(substring(tt.TextType, 8, len(CASE WHEN u.MTB_ConstituentID = -1 THEN NULL ELSE u.MTB_ConstituentID END) owner FROM ObjectPackages p LEFT OUTER JOIN Users u ON p.owner = u.login ; |
notes
- "global" field does not need to be imported, per Michael (1/12/12)
Object-Group Relationship extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjPkgList | ObjectID | objectID |
|
ObjPkgList | ObjectPackageID | groupID |
|
sql query
view: cs_objectgrouprelationships
Code Block | ||
---|---|---|
sql | sql | SELECT objectID, objectPackageID groupID FROM objPkgList ;tt.TextType))) + ': ' nagpraCulturalDetermination_prefix, t.TextEntry nagpraCulturalDetermination FROM TextEntries t JOIN Objects o ON t.ID = o.objectID JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID WHERE t.tableID = 108 AND o.IsVirtual = 0 AND o.IsTemplate = 0 AND t.TextTypeID = 121 ; |
notes
- NOTE: 'nagpraCulturalDetermination_prefix' should be prepended to 'nagpraCulturalDetermination' prior to import (this can't be done here because some fields are type TEXT which cannot be concatenated in SQL)
Repatriation note extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
TextEntries | textEntry | repatriationNote | where textTypeID is 81 |
sql query
view: cs_repatriationnotes (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
t.TextEntry repatriationNote
FROM
TextEntries t
JOIN Objects o ON t.ID = o.objectID
JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID
WHERE
t.tableID = 108
AND o.IsVirtual = 0 AND o.IsTemplate = 0
AND t.TextTypeID = 81
;
|
notes
Taxonomic determination history notes extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
TextEntries | textEntry | notes | where textTypeID is 96 |
sql query
view: cs_taxonomicdeterminationnotes (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
t.TextEntry notes
FROM
TextEntries t
JOIN Objects o ON t.ID = o.objectID
JOIN TextTypes tt ON t.TextTypeID = tt.TextTypeID
WHERE
t.tableID = 108
AND o.IsVirtual = 0 AND o.IsTemplate = 0
AND t.TextTypeID = 96
;
|
notes
Object Status
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | objectStatusID | Object Status (PAHMA schema) | FK to ObjectStatuses |
StatusFlags | FlagID | Object Status (PAHMA schema) | FK to FlagLabels |
sql query
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
s.ObjectStatus pahmaObjectStatus
FROM
Objects o
LEFT OUTER JOIN ObjectStatuses s ON o.objectStatusID = s.objectStatusID
WHERE
o.IsVirtual = 0 AND o.IsTemplate = 0
AND o.objectStatusID IS NOT NULL
UNION ALL
SELECT
CAST(sf.objectID AS VARCHAR) objectID,
fl.FlagLabel pahmaObjectStatus
FROM
StatusFlags sf
LEFT OUTER JOIN FlagLabels fl ON sf.FlagID = fl.FlagID
WHERE
fl.FlagID IS NOT NULL
ORDER BY objectID
|