diff --git a/mobile_verifier/migrations/38_coverage_objects_cascade_delete.sql b/mobile_verifier/migrations/38_coverage_objects_cascade_delete.sql new file mode 100644 index 000000000..f4b6b92fe --- /dev/null +++ b/mobile_verifier/migrations/38_coverage_objects_cascade_delete.sql @@ -0,0 +1,7 @@ +ALTER TABLE + hexes DROP CONSTRAINT IF EXISTS hexes_uuid_fkey; + +ALTER TABLE + hexes +ADD + CONSTRAINT hexes_uuid_fkey FOREIGN KEY (uuid) REFERENCES coverage_objects(uuid) ON DELETE CASCADE; \ No newline at end of file diff --git a/mobile_verifier/src/coverage.rs b/mobile_verifier/src/coverage.rs index e7178e177..5ef717084 100644 --- a/mobile_verifier/src/coverage.rs +++ b/mobile_verifier/src/coverage.rs @@ -363,6 +363,33 @@ impl CoverageObject { } } +pub async fn set_invalidated_at( + exec: &mut Transaction<'_, Postgres>, + invalidated_at: DateTime, + inserted_at: Option>, + radio_key: KeyType<'_>, + uuid: Option, +) -> anyhow::Result<()> { + sqlx::query( + r#" + UPDATE coverage_objects + SET invalidated_at = $1 + WHERE inserted_at < $2 + AND invalidated_at IS NULL + AND radio_key = $3 + AND uuid != $4 + "#, + ) + .bind(invalidated_at) + .bind(inserted_at) + .bind(radio_key) + .bind(uuid) + .execute(&mut *exec) + .await?; + + Ok(()) +} + #[derive(Debug, Clone, FromRow)] pub struct HexCoverage { pub uuid: Uuid, @@ -457,24 +484,42 @@ pub async fn clear_coverage_objects( tx: &mut Transaction<'_, Postgres>, timestamp: &DateTime, ) -> Result<(), sqlx::Error> { - // Delete any hex coverage objects that were invalidated before the given timestamp - sqlx::query( - r#" - DELETE FROM hexes WHERE uuid IN ( - SELECT uuid - FROM coverage_objects - WHERE invalidated_at < $1 - ) - "#, - ) - .bind(timestamp) - .execute(&mut *tx) - .await?; + // We do not delete hexes here anymore because `38_coverage_objects_cascade_delete.sql` add CONSTRAINT ON DELETE CASCADE + // Remove all invalidated objects before timestamp sqlx::query("DELETE FROM coverage_objects WHERE invalidated_at < $1") .bind(timestamp) .execute(&mut *tx) .await?; + + // Delete all but the last 10 valid coverage_objects entry per radio_key before a given timestamp + sqlx::query( + r#" + WITH orphan_coverage_objects AS ( + SELECT + uuid + FROM ( + SELECT + uuid, + radio_key, + inserted_at, + ROW_NUMBER() OVER (PARTITION BY radio_key ORDER BY inserted_at DESC) AS row_num + FROM + coverage_objects + WHERE + invalidated_at IS NULL AND inserted_at < $1 + ) AS ranked_rows + WHERE row_num > 10 + ) + DELETE FROM coverage_objects + USING orphan_coverage_objects + WHERE coverage_objects.uuid = orphan_coverage_objects.uuid; + "#, + ) + .bind(timestamp) + .execute(&mut *tx) + .await?; + Ok(()) } diff --git a/mobile_verifier/src/heartbeats/mod.rs b/mobile_verifier/src/heartbeats/mod.rs index b941aa7ee..989f9d187 100644 --- a/mobile_verifier/src/heartbeats/mod.rs +++ b/mobile_verifier/src/heartbeats/mod.rs @@ -4,7 +4,7 @@ pub mod wifi; use crate::{ cell_type::{CellType, CellTypeLabel}, - coverage::{CoverageClaimTimeCache, CoverageObjectCache, CoverageObjectMeta}, + coverage::{self, CoverageClaimTimeCache, CoverageObjectCache, CoverageObjectMeta}, geofence::GeofenceValidator, seniority::{Seniority, SeniorityUpdate}, GatewayResolution, GatewayResolver, @@ -650,21 +650,13 @@ impl ValidatedHeartbeat { } pub async fn save(self, exec: &mut Transaction<'_, Postgres>) -> anyhow::Result<()> { - sqlx::query( - r#" - UPDATE coverage_objects - SET invalidated_at = $1 - WHERE inserted_at < $2 - AND invalidated_at IS NULL - AND radio_key = $3 - AND uuid != $4 - "#, + coverage::set_invalidated_at( + exec, + self.heartbeat.timestamp, + self.coverage_meta.as_ref().map(|x| x.inserted_at), + self.heartbeat.key(), + self.heartbeat.coverage_object, ) - .bind(self.heartbeat.timestamp) - .bind(self.coverage_meta.as_ref().map(|x| x.inserted_at)) // Guaranteed not to be NULL - .bind(self.heartbeat.key()) - .bind(self.heartbeat.coverage_object) - .execute(&mut *exec) .await?; // Save the heartbeat match self.heartbeat.hb_type {