...
Table of Contents | ||
---|---|---|
|
Page Tree | ||||
---|---|---|---|---|
|
Collection Objects extract
...
TMS table name | TMS field name | CSpace field name | notes | ||||||||
---|---|---|---|---|---|---|---|---|---|---|---|
Objects | ObjectID | pahmaObjectID |
| ||||||||
ObjComponents | ComponentID | pahmaObjectID | must ensure no duplicates with Objects.ObjectID | ||||||||
Objects | ObjectNumber | objectNumber |
| ||||||||
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 | fieldCollectionPlace | reference to Place Authority | Objects | Notes | comments |
|
Objects | ObjectStatusID | pahmaObjectStatus FK to ObjectStatuses; NEW field (controlled list) | 6/12/2012: deprecated. Object Status becoming a repeating field. | ||||||||
Objects | ObjectTypeID | collection | FK to ObjectTypes | ||||||||
Objects | 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; controlled list | ||||||||
Objects ObjContext | State Integer3 | pahmaNagpraCodeLegacy | controlled list | ||||||||
Objects | Title | title |
| ||||||||
ObjContext | Integer3 | inventoryCount | inventoryCount | NEW field |
sql query
view: cs_objects (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, o.ObjectNumber objectNumber, '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 fieldLocVerbatim, (CASE WHEN o.MTB_ResponsibleDept = 1 THEN 'Natasha Johnson' WHEN 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, Signed inscriptionContent, b.optionID 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.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 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 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 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
- DONE: add isComponent field for indicating components
Object-Object Relationships extract
sql query
view: cs_objectobjectrelationships
...
- 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) childObjectIDobjectID_1, FROM 'c' ObjComponents+ 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) ; |
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 |
|
ObjComponents | CompCount | numberOfObjects |
|
sql query
view: cs_numberofobjects
Code Block | ||
---|---|---|
sql | sql | SELECT CAST(o.objectIDUNION ALL SELECT CAST(oa.ID1 AS VARCHAR) objectID_1, CAST(oa.ID2 AS VARCHAR) objectID_2, o.objectCount numberOfObjects FROM Objects or.relation1 + '-' + r.relation2 relationshipType FROM Associations oa, Objects obj1, Objects obj2, Relationships r WHERE ooa.IsVirtualtableID = 0108 AND ooa.IsTemplateID1 = 0obj1.objectID AND ooa.objectIDID2 NOT IN (SELECT t= obj2.objectID FROM ObjComponentsAND tobj1.IsVirtual GROUP= BY0 tAND obj1.objectID HAVING count(*) IsTemplate = 1)0 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.objectIDAND 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 co.objectID NOT IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) UNION ALL SELECT 'c' + CAST(c.componentIDCAST(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 WHEREON o.objectID = c.objectID INWHERE (SELECT to.objectIDIsVirtual FROM= ObjComponents0 tAND GROUPo.IsTemplate BY= t.objectID 0 AND c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) >= 1) ; |
notes
...
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 |
---|---|---|---|
AltNums | AltNum | pahmaAltNum |
|
ObjComponents | ComponentNumber | pahmaAltNum |
|
AltNums | Description | pahmaAltNumType | controlled list |
AltNums | Remarks | pahmaAltNumNote |
|
...
view: cs_alternatenumbers
...
(refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(n.ID AS VARCHAR) objectID,
n.altnum pahmaAltNum,
n.description pahmaAltNumType,
n.remarks pahmaAltNumNote
FROM
AltNums n
WHERE
n.tableID = 108
AND n.altnum IS NOT NULL
UNION ALL
SELECT
CAST(c.objectID AS VARCHAR) 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
;
|
...
- 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 o.objectName IS NOT NULL UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.componentName objectName, NULL objectNameLanguage, 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 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.componentName IS NOT NULL 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 END) objectNameLanguage, + ')''' + (CASE WHEN n.objectNameTypeID != '0' THEN t.objectNameType ELSE '' END) +charindex('/', l.language) > 0 THEN substring(l.language, 1, charindex('/', l.language) - 1) ELSE l.language END) + '''' END) objectNameLanguage, (CASE WHEN n.objectNameTypeID != '0' ANDTHEN nt.remarksobjectNameType is 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 ; |
...
Brief Descriptions extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | description | briefDescription |
|
ObjComponents | physDesc | briefDescription |
|
TextEntries | textEntry | briefDescription | where textTypeID is 6, 7, or 23 |
sql query
view: cs_briefdescriptions (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(o.objectID AS VARCHAR) objectID, o.description briefDescription 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 ; |
Object Titles extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
ObjTitles | Title | title |
|
ObjTitles | LanguageID | titleLanguage | FK to Languages |
ObjTitles | TitleTypeID | titleType | FK to TitleTypes |
sql query
view: cs_objecttitles
Code Block | ||
---|---|---|
sql | sql | UNION ALL SELECT CAST(no.objectID AS VARCHAR) objectID, nt.title,TextEntry briefDescription (CASE WHEN n.languageID != '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)
- 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
...
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_ethnographicfilecodesobjecttitles (refreshed 2012-03-22)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT CAST(uo.objectID AS VARCHAR) objectID, Title title, NULL titleLanguage, c.CSoptionIDNULL pahmaEthnographicFileCodetitleType FROM ObjUserFieldsObjects o uWHERE JOIN MTB_EthnographicUseCodes c ON u.FieldValueo.IsVirtual = 0 AND o.IsTemplate = c.FieldValue0 WHERE AND 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
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
Code Block | ||
---|---|---|
sql | sql | SELECT CAST(d.objectID AS VARCHAR) objectID, lower(d.eventType) assocDateType, d.dateText assocDate_dateDisplayDateo.title IS NOT NULL UNION ALL SELECT CAST(n.objectID AS VARCHAR) objectID, n.title, (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) titleLanguage, (CASE WHEN dn.dateBegSearchtitleTypeID != '0' THEN dt.dateBegSearchtitleType END) assocDate_dateEarliestSingleYear,titleType FROM (CASE WHENobjTitles d.dateEndSearchn != '0'LEFT THENOUTER d.dateEndSearch END) assocDate_dateLatestYear, d.dayBegSearch assocDate_dateEarliestSingleDay, d.dayEndSearch assocDate_dateLatestDay, d.monthBegSearch assocDate_dateEarliestSingleMonth, d.monthEndSearch assocDate_dateLatestMonth, d.remarks assocDateNote FROM ObjDates d WHERE lower(d.eventType) not in ('', 'accessioned', 'date collected', 'secondary collection date', 'tertiary collection date', 'date made') AND (d.dateText is not null OR d.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
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_fieldcollectiondates
...
_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 |
---|---|---|---|
Objects | Notes | comment |
|
TextEntries | textEntry | comment | where textTypeID is 27 |
sql query
view: cs_objectcomments (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
o.dated fieldCollectionDate_dateDisplayDate,
(CASE WHEN o.dateBegin != '0' THEN o.dateBegin END) fieldCollectionDate_dateEarliestSingleYear,
(CASE WHEN o.dateEnd != '0' THEN o.dateEnd END) fieldCollectionDate_dateLatestYear,
null fieldCollectionDate_dateEarliestSingleDay,
null fieldCollectionDate_dateLatestDay,
null fieldCollectionDate_dateEarliestSingleMonth,
null fieldCollectionDate_dateLatestMonth,
null fieldCollectionNote
FROM
Objects o
WHERE
o.dated IS NOT NULL OR o.dateBegin != '0' OR o.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)
- DONE: add new field pahmaFieldCollectionDate, to change fieldCollectionDate field into a repeating field
- TODO: wait until fieldCollectionDate field is changed into a structured date (in v2.1; see CSPACE-4775)
...
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 |
---|---|---|---|
ObjDates | DateText | objectProductionDate_dateDisplayDate |
|
ObjDates | DateBegSearch | 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
CAST(d.objectID AS VARCHAR) objectID,
d.dateText objectProductionDate_dateDisplayDate,
(CASE WHEN d.dateBegSearch != '0' THEN d.dateBegSearch END) objectProductionDate_dateEarliestSingleYear,
(CASE WHEN d.dateEndSearch != '0' THEN d.dateEndSearch END) objectProductionDate_dateLatestYear,
d.dayBegSearch objectProductionDate_dateEarliestSingleDay,
d.dayEndSearch objectProductionDate_dateLatestDay,
d.monthBegSearch objectProductionDate_dateEarliestSingleMonth,
d.monthEndSearch objectProductionDate_dateLatestMonth,
d.remarks objectProductionNote
FROM
ObjDates d
WHERE
lower(d.eventType) = 'date made'
;
notes
Bibliographic References extract
field mapping
TMS table name | TMS field name | CSpace field name | notes |
---|---|---|---|
Objects | Bibliography | referenceNote |
|
Objects | PubReferences | referenceNote |
|
sql query
view: cs_bibliographicreferences
...
SELECT
CAST(o.objectID AS VARCHAR) objectID,
o.bibliography referenceNote
FROM
Objects o
WHERE
o.bibliography is not null
UNION ALL
SELECT
CAST(o.objectID AS VARCHAR) objectID,
o.PubReferences referenceNote
FROM
Objects o
WHERE
o.PubReferences is not null
;
...
TextEntries | textEntry | materialComponentNote | where textTypeID is 37 or 92 |
sql query
view: cs_materialsnotes (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
(CASE WHEN t.textTypeID = 37 THEN 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 |
---|---|---|---|
TextEntries | textEntry | nagpraCulturalDetermination | where textTypeID is 121 |
sql query
view: cs_nagpraculturaldeterminations (refreshed 2012-04-10)
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT
CAST(o.objectID AS VARCHAR) objectID,
substring(tt.TextType, 1, 7) + lower(substring(tt.TextType, 8, len(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 |
---|---|---|---|
Objects | Edition | annotationNote |
|
Objects | CuratorialRemarks | annotationNote |
|
Components | PrepComments | annotationNote |
|
ObjUserFields | FieldValue | annotationNote |
|
sql query
view: cs_annotations
...
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, ct.prepComments annotationNote, 'Component Prep comments' annotationType TextEntry repatriationNote FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) = 1) AND c.prepComments IS NOT NULL UNION ALL SELECT 'c' + CAST(c.componentID AS VARCHAR) objectID, c.prepComments annotationNote, 'Component Prep comments' annotationType FROM ObjComponents c WHERE c.objectID IN (SELECT t.objectID FROM ObjComponents t GROUP BY t.objectID HAVING count(*) > 1) AND c.prepComments IS NOT NULL UNION ALL SELECT CAST(u.objectID AS VARCHAR) objectID, u.fieldValue annotationNote, t.userFieldType annotationType FROM ObjUserFields u JOIN UserFieldTypes t ON u.fieldTypeID = t.userFieldTypeID WHERE u.FieldTypeID != 17 ; |
notes
- some annotationType field values set by query above
- TODO: update controlled list options for annotationType field
- TODO: include some data from TextEntries table in this query...?
Groups extract
...
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 |
---|---|---|---|
ObjectPackages Objects | name | title |
|
ObjectPackages | notes | scopeNote |
|
ObjectPackages | owner | owner | FK to Users; reference to Person Authority |
sql query
view: cs_groups
objectStatusID | Object Status (PAHMA schema) | FK to ObjectStatuses | |
StatusFlags | FlagID | Object Status (PAHMA schema) | FK to FlagLabels |
sql query
Code Block | ||||
---|---|---|---|---|
| ||||
SELECT pCAST(o.objectPackageIDobjectID groupID,AS p.name titleVARCHAR) objectID, ps.notesObjectStatus scopeNote,pahmaObjectStatus FROM (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 | reference to Object |
|
ObjPkgList | ObjectPackageID | reference to Group |
|
sql query
view: cs_objectgrouprelationships
Code Block | ||
---|---|---|
sql | sql | 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(osf.objectID AS VARCHAR) objectID, ofl.objectPackageIDFlagLabel groupIDpahmaObjectStatus FROM objPkgList o ;StatusFlags sf LEFT OUTER JOIN FlagLabels fl ON sf.FlagID = fl.FlagID WHERE fl.FlagID IS NOT NULL ORDER BY objectID |