Omaha #4677: Update PK column of bufrmos_location

Change-Id: I265ad75ecaad2f1d829cdcd22ca7de3fc8e67299

Former-commit-id: 22d027cf0f7b0144473c7d3cf471d6d17ff51383
This commit is contained in:
Tom Gurney 2016-01-12 13:34:33 -06:00
parent 564b29a3c7
commit 31117fcda3
2 changed files with 200 additions and 1 deletions

View file

@ -0,0 +1,193 @@
#!/bin/bash
# DR #4677 - This script replaces all PKs in bufrmos_location with
# sequence-generated values, and cascades the update to all
# referencing tables.
PSQL="/awips2/psql/bin/psql"
# Given table name as argument, return the name of the FK constraint
# referencing bufrmos_location.
get_constraint_name() {
${PSQL} -U awips -Aqt -d metadata << EOF
SELECT tc.constraint_name
FROM information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
WHERE constraint_type = 'FOREIGN KEY'
AND tc.table_name='$1'
and ccu.table_name = 'bufrmos_location';
EOF
}
# Check for existence of bufrmos_locationseq
sequence_exists() {
${PSQL} -U awips -Aqt -d metadata << EOF
select 0
from information_schema.sequences
where sequence_name = 'bufrmos_locationseq'
EOF
}
get_min_pk() {
${PSQL} -U awips -Aqt -d metadata << EOF
select min(id) id
from bufrmos_location;
EOF
}
get_max_pk() {
${PSQL} -U awips -Aqt -d metadata << EOF
select max(id) id
from bufrmos_location;
EOF
}
last_bufrmos_locationseq_value() {
${PSQL} -U awips -Aqt -d metadata -c \
"select last_value from bufrmos_locationseq;"
}
if [[ "$(sequence_exists)" != "0" ]]; then
echo "INFO: bufrmos_locationseq does not exist in the database"
echo "INFO: Attempting to create bufrmos_locationseq"
${PSQL} -U awips -d metadata -c \
"create sequence bufrmos_locationseq increment 1 start 1;"
if [[ "$?" != "0" || "$(sequence_exists)" != "0" ]]; then
echo "ERROR: Failed to create bufrmos_locationseq"
exit 1
else
echo "INFO Successfully created bufrmos_locationseq"
fi
fi
min_pk="$(get_min_pk)"
max_pk="$(get_max_pk)"
if [[ ("$min_pk" -gt 0) && ("$max_pk" -le "$(last_bufrmos_locationseq_value)") ]]; then
echo "WARN: Looks like PKs were already updated."
echo "WARN: (smallest PK found: ${min_pk})"
echo "WARN: (largest PK found: ${max_pk})"
echo "WARN: Doing nothing."
exit 0
fi
fk_bufrmosavn=`get_constraint_name bufrmosavn`
fk_bufrmoseta=`get_constraint_name bufrmoseta`
fk_bufrmosgfs=`get_constraint_name bufrmosgfs`
fk_bufrmoshpc=`get_constraint_name bufrmoshpc`
fk_bufrmoslamp=`get_constraint_name bufrmoslamp`
fk_bufrmosmrf=`get_constraint_name bufrmosmrf`
fk_bufrmosngm=`get_constraint_name bufrmosngm`
echo "INFO: Updating all PKs of bufrmos_location"
echo "INFO: This may take a few minutes..."
${PSQL} -U awips -d metadata << EOF
begin transaction;
alter table bufrmosavn
drop constraint ${fk_bufrmosavn},
add constraint ${fk_bufrmosavn}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmoseta
drop constraint ${fk_bufrmoseta},
add constraint ${fk_bufrmoseta}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmosgfs
drop constraint ${fk_bufrmosgfs},
add constraint ${fk_bufrmosgfs}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmoshpc
drop constraint ${fk_bufrmoshpc},
add constraint ${fk_bufrmoshpc}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmoslamp
drop constraint ${fk_bufrmoslamp},
add constraint ${fk_bufrmoslamp}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmosmrf
drop constraint ${fk_bufrmosmrf},
add constraint ${fk_bufrmosmrf}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
alter table bufrmosngm
drop constraint ${fk_bufrmosngm},
add constraint ${fk_bufrmosngm}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE CASCADE ON DELETE NO ACTION;
UPDATE bufrmos_location
SET id=nextval('bufrmos_locationseq');
alter table bufrmosavn
drop constraint ${fk_bufrmosavn},
add constraint ${fk_bufrmosavn}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmoseta
drop constraint ${fk_bufrmoseta},
add constraint ${fk_bufrmoseta}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmosgfs
drop constraint ${fk_bufrmosgfs},
add constraint ${fk_bufrmosgfs}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmoshpc
drop constraint ${fk_bufrmoshpc},
add constraint ${fk_bufrmoshpc}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmoslamp
drop constraint ${fk_bufrmoslamp},
add constraint ${fk_bufrmoslamp}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmosmrf
drop constraint ${fk_bufrmosmrf},
add constraint ${fk_bufrmosmrf}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
alter table bufrmosngm
drop constraint ${fk_bufrmosngm},
add constraint ${fk_bufrmosngm}
FOREIGN KEY (location_id)
REFERENCES bufrmos_location (id) MATCH SIMPLE
ON UPDATE NO ACTION ON DELETE NO ACTION;
commit transaction;
EOF
echo "INFO: Done."

View file

@ -21,12 +21,15 @@ package com.raytheon.uf.common.dataplugin.bufrmos.common;
import javax.persistence.Column;
import javax.persistence.Entity;
import javax.persistence.GeneratedValue;
import javax.persistence.Id;
import javax.persistence.SequenceGenerator;
import javax.persistence.Table;
import javax.persistence.UniqueConstraint;
import org.hibernate.annotations.Index;
import com.raytheon.uf.common.dataplugin.PluginDataObject;
import com.raytheon.uf.common.dataplugin.annotations.DataURI;
import com.raytheon.uf.common.dataplugin.annotations.NullFloat;
import com.raytheon.uf.common.dataplugin.annotations.NullString;
@ -50,6 +53,7 @@ import com.raytheon.uf.common.serialization.annotations.DynamicSerializeElement;
* Nov 04, 2013 2361 njensen Remove XML annotations
* Jul 22, 2015 4360 rferrel Named unique constraint;
* stationid, latitude and longitude no longer nullable.
* Jan 12, 2016 4677 tgurney Make id a sequence-generated field.
*
* </pre>
*
@ -57,6 +61,7 @@ import com.raytheon.uf.common.serialization.annotations.DynamicSerializeElement;
* @version 1.0
*/
@Entity
@SequenceGenerator(initialValue = 1, name = PluginDataObject.ID_GEN, sequenceName = "bufrmos_locationseq", allocationSize = 1)
@Table(name = "bufrmos_location", uniqueConstraints = { @UniqueConstraint(name = "uk_bufrmos_location_datauri_fields", columnNames = {
"stationId", "latitude", "longitude" }) })
@DynamicSerialize
@ -64,8 +69,9 @@ public class BufrMosDataLocation extends PersistableDataObject {
private static final long serialVersionUID = 1L;
/** The id */
@Id
@DynamicSerializeElement
@GeneratedValue(generator = PluginDataObject.ID_GEN)
@Id
private Integer id;
// Id of the station making this observation.