view schema/geo_functions.sql @ 4161:64cd18281c76

Improve performance of row level security policies Using constraint_column_usage instead of key_column_usage makes the query twice as fast. I did not explore why. Let's just take it. Using 'EXISTS(... WHERE ... = value) is often more efficient than value IN(...) since it allows the inner query to be executed only up to the point where it turns out to return more than nothing with filtering directly in place.
author Tom Gottfried <tom@intevation.de>
date Fri, 02 Aug 2019 17:14:13 +0200
parents eeeb7bf14217
children
line wrap: on
line source

-- This is Free Software under GNU Affero General Public License v >= 3.0
-- without warranty, see README.md and license for details.

-- SPDX-License-Identifier: AGPL-3.0-or-later
-- License-Filename: LICENSES/AGPL-3.0.txt

-- Copyright (C) 2018, 2019 by via donau
--   – Österreichische Wasserstraßen-Gesellschaft mbH
-- Software engineering by Intevation GmbH

-- Author(s):
--  * Sascha L. Teichmann <sascha.teichmann@intevation.de>
--  * Tom Gottfried <tom@intevation.de>

CREATE OR REPLACE FUNCTION best_utm(g geography) RETURNS integer AS
$$
DECLARE
  center geometry;
BEGIN
  -- Centroid should be calculated on geography to get accurate results
  -- from lon/lat coordinates, but the respective PostGIS function returns
  -- POINT(-NaN NaN) for some invalid polygons, while the calculation on
  -- geometry seems to give reasonable approximations in this context.
  SELECT ST_Centroid(CAST(g AS geometry)) INTO center;

  RETURN
    CASE WHEN ST_Y(center) > 0 THEN
    32600
  ELSE
    32700
  END + floor((ST_X(center)+180)/6)::int + 1;
END;
$$
LANGUAGE plpgsql
IMMUTABLE;