Missing Local ID PGSQL
| All ID are important to be filled in. Form ID is important for the DEF's Reconcilation tab and I recommend that to update Form ID after you have have checked the items' ID.
There is a MySQL version of this page too. |
Missing Local ID items items

How it should NOT look like
Start with checking the items and the infoversions. If they are missing a local ID then I strongly recommend to set one which will be very helpful if you need to populate Form ID.
Missing ID - Accident
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT accident.accident_localid AS Acc_ID, accidentinfoversion.accident_localid FROM accident Inner Join accidentinfoversion ON accident.accident_guid = accidentinfoversion.accident_guid WHERE (accident.accident_localid IS NULL OR accidentinfoversion.accident_localid IS NULL OR length(trim(accident.accident_localid)) = 0 OR length(trim(accidentinfoversion.accident_localid)) = 0) AND accidentinfoversion.link_only = 'f' ORDER BY accident.accident_localid ASC
Missing ID - Hazard
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT hazard.hazard_localid AS Haz_ID, hazardinfoversion.hazard_localid FROM hazardinfoversion Inner Join hazard ON hazardinfoversion.hazard_guid = hazard.hazard_guid WHERE hazardinfoversion.link_only = 'f' AND (hazardinfoversion.hazard_localid IS NULL OR hazard.hazard_localid IS NULL OR length(trim(hazardinfoversion.hazard_localid))= 0 OR length(trim(hazard.hazard_localid)) = 0 ) ORDER BY hazard.hazard_localid ASC
Missing ID - Hazard Reduction
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT hazreduc.hazreduc_localid AS HR_ID, hazreducinfoversion.hazreduc_localid FROM hazreducinfoversion Inner Join hazreduc ON hazreducinfoversion.hazreduc_guid = hazreduc.hazreduc_guid WHERE (hazreducinfoversion.hazreduc_localid IS NULL OR hazreduc.hazreduc_localid IS NULL OR length(trim(hazreducinfoversion.hazreduc_localid)) = 0 OR length(trim(hazreduc.hazreduc_localid)) = 0 ) AND hazreducinfoversion.link_only = 'f' ORDER BY hazreduc.hazreduc_localid ASC
Missing ID - Location
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT location.location_localid AS Loc_ID, locationinfoversion.location_localid FROM locationinfoversion Inner Join location ON locationinfoversion.location_guid = location.location_guid WHERE (locationinfoversion.location_localid IS NULL OR location.location_localid IS NULL OR length(trim(locationinfoversion.location_localid)) = 0 OR length(trim(location.location_localid)) = 0) AND locationinfoversion.link_only = 'f' ORDER BY location.location_localid ASC
Missing ID - MRE
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT mre.mre_localid AS MRE_ID, mreinfoversion.mre_localid FROM mreinfoversion Inner Join mre ON mreinfoversion.mre_guid = mre.mre_guid WHERE (mreinfoversion.mre_localid IS NULL OR mre.mre_localid IS NULL OR length(trim(mreinfoversion.mre_localid)) = 0 OR length(trim(mre.mre_localid)) = 0) AND mreinfoversion.link_only = 'f' ORDER BY mre.mre_localid ASC
Missing ID - QM
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT qa.qa_localid AS QM_ID, qainfoversion.qa_localid FROM qainfoversion Inner Join qa ON qainfoversion.qa_guid = qa.qa_guid WHERE (qainfoversion.qa_localid IS NULL OR qa.qa_localid IS NULL OR length(trim(qainfoversion.qa_localid)) = 0 OR length(trim(qa.qa_localid))= 0) AND qainfoversion.link_only = 'f' ORDER BY qa.qa_localid ASC
Missing ID - Victim
If you get output here you need to take action. From the result set you can figure out a solution depending on if it is the item, the infoversion or both that are missing the Local ID.
SELECT victim.victim_localid AS Vic_ID, victiminfoversion.victim_localid FROM victiminfoversion Inner Join victim ON victiminfoversion.victim_guid = victim.victim_guid WHERE (victiminfoversion.victim_localid IS NULL OR victim.victim_localid IS NULL OR length(trim(victiminfoversion.victim_localid))= 0 OR length(trim(victim.victim_localid))= 0) AND victiminfoversion.link_only = 'f' ORDER BY victim.victim_localid ASC
Missing Local ID items - Example update query
update hazardinfoversion SET hazard_localid = hazard.hazard_localid FROM hazard WHERE hazardinfoversion.hazard_guid = hazard.hazard_guid AND hazardinfoversion.link_only = 'f' AND hazardinfoversion.hazard_localid IS NULL and hazard.hazard_localid IS NOT NULL
Missing Local ID fieldreport

How it should NOT look like
If you get output here you NEED to take action. The easiest solution to populate the Form ID for DEF is to use the local ID from the infoversion which you have now populated with updating the ones that were missing with the queries above.
SELECT fieldreport.fieldreport_localid, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", imsmaenum.enumvalue, fieldreportdesc.fieldreportname FROM fieldreport Inner Join imsmaenum ON fieldreport.workbenchstatusenum_guid = imsmaenum.imsmaenum_guid Inner Join fieldreportdesc ON fieldreport.fieldreportdesc_guid = fieldreportdesc.fieldreportdesc_guid WHERE fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0 ORDER BY imsmaenum.enumvalue ASC, fieldreportdesc.fieldreportname ASC
If you have any output here you need to take action. The queries below help you to identify for which item(s) the rows in the table fieldreport need to be updated and if you have any data that you could use.
Missing ID fieldreport - Accident
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", accidentinfoversion.accident_localid FROM fieldreport Inner Join accidentinfoversion ON fieldreport.fieldreport_guid = accidentinfoversion.fieldreport_guid Inner Join imsmaenum ON fieldreport.workbenchstatusenum_guid = imsmaenum.imsmaenum_guid WHERE (fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0 ) AND accidentinfoversion.link_only = 'f'
Missing ID fieldreport - Hazard
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", hazardinfoversion.hazard_localid FROM fieldreport Inner Join hazardinfoversion ON fieldreport.fieldreport_guid = hazardinfoversion.fieldreport_guid Inner Join imsmaenum ON fieldreport.workbenchstatusenum_guid = imsmaenum.imsmaenum_guid WHERE (fieldreport.fieldreport_localid IS NULL OR length(trim(fieldreport.fieldreport_localid)) = 0) AND hazardinfoversion.link_only = 'f'
Missing ID fieldreport - Hazard Reduction
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", hazreducinfoversion.hazreduc_localid FROM fieldreport Inner Join hazreducinfoversion ON hazreducinfoversion.fieldreport_guid = fieldreport.fieldreport_guid Inner Join imsmaenum ON imsmaenum.imsmaenum_guid = fieldreport.workbenchstatusenum_guid WHERE (fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0) AND hazreducinfoversion.link_only = 'f' AND hazreducinfoversion.hazreduc_localid IS NOT NULL
Missing ID fieldreport - Location
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", locationinfoversion.location_localid FROM fieldreport Inner Join locationinfoversion ON locationinfoversion.fieldreport_guid = fieldreport.fieldreport_guid Inner Join imsmaenum ON fieldreport.workbenchstatusenum_guid = imsmaenum.imsmaenum_guid WHERE (fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0 ) AND locationinfoversion.link_only = 'f'
Missing ID fieldreport - MRE
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", mreinfoversion.mre_localid FROM fieldreport Inner Join mreinfoversion ON mreinfoversion.fieldreport_guid = fieldreport.fieldreport_guid Inner Join imsmaenum ON imsmaenum.imsmaenum_guid = fieldreport.workbenchstatusenum_guid WHERE ( fieldreport.fieldreport_localid is null or length(trim(fieldreport.fieldreport_localid)) = 0) AND mreinfoversion.link_only = 'f'
Missing ID fieldreport - QM
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", qainfoversion.qa_localid FROM fieldreport Inner Join qainfoversion ON qainfoversion.fieldreport_guid = fieldreport.fieldreport_guid Inner Join imsmaenum ON imsmaenum.imsmaenum_guid = fieldreport.workbenchstatusenum_guid WHERE (fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0) AND qainfoversion.link_only = 'f'
Missing ID fieldreport - Victim
SELECT fieldreport.fieldreport_localid, imsmaenum.enumvalue, fieldreport.dateofreport AS "Date of Information", fieldreport.reportreceiveddate AS "Data Entry Date", fieldreport.reportcompleteddate AS "Submitted Date", fieldreport.reportverifieddate AS "Approved Date", fieldreport.dataenterer AS "Data enterer", fieldreport.verifiedby AS "Approved by", victiminfoversion.victim_localid FROM fieldreport Inner Join victiminfoversion ON fieldreport.fieldreport_guid = victiminfoversion.fieldreport_guid Inner Join imsmaenum ON fieldreport.workbenchstatusenum_guid = imsmaenum.imsmaenum_guid WHERE (fieldreport.fieldreport_localid IS NULL or length(trim(fieldreport.fieldreport_localid)) = 0) AND victiminfoversion.link_only = 'f'
Missing ID fieldreport - Example update query

update fieldreport SET fieldreport_localid = 'DEF-' || trim(hazardinfoversion.hazard_localid) FROM hazardinfoversion WHERE hazardinfoversion.fieldreport_guid = fieldreport.fieldreport_guid AND (fieldreport.fieldreport_localid is null or length(trim(fieldreport.fieldreport_localid)) = 0) and hazardinfoversion.link_only = 'f' AND hazardinfoversion.hazard_localid IS NOT NULL
Missing Local ID Auxiliary data and Task
Country structure
In 5.x the Country Structure ID was not visible in the editor and therefore many countries will have blank here. To have a proper ID will facilitate Country structure updates which happens regularly.
SELECT "public".gazetteer.gazetteer_localid, "public".gazetteer.gazetteername, "public".gazetteerlevel."level" FROM "public".gazetteer INNER JOIN "public".gazetteerlevel ON "public".gazetteer.gazlevel_guid = "public".gazetteerlevel.gazlevel_guid WHERE "public".gazetteer.gazetteer_localid IS NULL OR length(trim(gazetteer_localid)) = 0 ORDER BY "public".gazetteer.gazetteername ASC
Organisation
SELECT "public".organisation.org_localid, "public".organisation.orgname, "public".organisation.parentorg_guid FROM organisation WHERE org_localid IS NULL OR length(trim(org_localid)) = 0 ORDER BY "public".organisation.orgname ASC
Place
SELECT "public".place.place_localid, "public".place.placename FROM place WHERE place_localid IS NULL OR length(trim(place_localid)) = 0 ORDER BY "public".place.placename ASC
Task
SELECT "public".task.localid, "public".task."name" FROM task WHERE task.localid IS NULL or length(trim(task.localid))=0 ORDER BY "public".task."name" ASC
Work item
SELECT "public".work_item.localid, "public".work_item."name" FROM work_item WHERE work_item.localid IS NULL OR length(trim(work_item.localid)) = 0 ORDER BY "public".work_item."name" ASC