Add database upgrade file 07

This commit is contained in:
D. Berge
2021-09-04 19:07:54 +02:00
parent 45fe467a21
commit a280a910f5

View File

@@ -0,0 +1,91 @@
-- Upgrade the database from commit 81d9ea19 to 0a10c897.
--
-- NOTE: This upgrade must be applied to every schema in the database.
-- NOTE: Each application starts a transaction, which must be committed
-- or rolled back.
--
-- This defines a new function ij_error(line, point, geometry) which
-- returns the crossline and inline distance (in metres) between the
-- geometry (which must be a point) and the preplot corresponding to
-- line / point.
--
-- To apply, run as the dougal user, for every schema in the database:
--
-- psql <<EOF
-- SET search_path TO survey_*,public;
-- \i $THIS_FILE
-- COMMIT;
-- EOF
--
-- NOTE: It can be applied multiple times without ill effect.
BEGIN;
-- Return the crossline, inline error of `geom` with respect to `line` and `point`
-- in the project's binning grid.
CREATE OR REPLACE FUNCTION ij_error(line double precision, point double precision, geom public.geometry)
RETURNS public.geometry(Point, 0)
LANGUAGE plpgsql STABLE LEAKPROOF
AS $$
DECLARE
bp jsonb := binning_parameters();
ij public.geometry := to_binning_grid(geom, bp);
theta numeric := (bp->>'theta')::numeric * pi() / 180;
I_inc numeric DEFAULT 1;
J_inc numeric DEFAULT 1;
I_width numeric := (bp->>'I_width')::numeric;
J_width numeric := (bp->>'J_width')::numeric;
a numeric := (I_inc/I_width) * cos(theta);
b numeric := (I_inc/I_width) * -sin(theta);
c numeric := (J_inc/J_width) * sin(theta);
d numeric := (J_inc/J_width) * cos(theta);
xoff numeric := (bp->'origin'->>'I')::numeric;
yoff numeric := (bp->'origin'->>'J')::numeric;
E0 numeric := (bp->'origin'->>'easting')::numeric;
N0 numeric := (bp->'origin'->>'northing')::numeric;
error_i double precision;
error_j double precision;
BEGIN
error_i := (public.st_x(ij) - line) * I_width;
error_j := (public.st_y(ij) - point) * J_width;
RETURN public.ST_MakePoint(error_i, error_j);
END
$$;
-- Return the list of points and metadata for all sequences.
-- Only points which have a corresponding preplot are returned.
-- If available, final positions are returned as well, if not they
-- are NULL.
-- Likewise, crossline / inline errors are also returned as a PostGIS
-- 2D point both for raw and final data.
CREATE OR REPLACE VIEW sequences_detail AS
SELECT
rl.sequence, rl.line AS sailline,
rs.line, rs.point,
rs.tstamp,
rs.objref objRefRaw, fs.objref objRefFinal,
ST_Transform(pp.geometry, 4326) geometryPreplot,
ST_Transform(rs.geometry, 4326) geometryRaw,
ST_Transform(fs.geometry, 4326) geometryFinal,
ij_error(rs.line, rs.point, rs.geometry) errorRaw,
ij_error(rs.line, rs.point, fs.geometry) errorFinal,
json_build_object('preplot', pp.meta, 'raw', rs.meta, 'final', fs.meta) meta
FROM
raw_lines rl
INNER JOIN raw_shots rs USING (sequence)
INNER JOIN preplot_points pp ON rs.line = pp.line AND rs.point = pp.point
LEFT JOIN final_shots fs ON rl.sequence = fs.sequence AND rs.point = fs.point;
--
--NOTE Run `COMMIT;` now if all went well
--