schemas/_regproc.postgres.sql
author Aurelien Campeas <aurelien.campeas@logilab.fr>
Wed, 03 Jul 2013 14:33:27 +0200
branchstable
changeset 9130 0f1504a9fb51
parent 4321 80b455066c9a
child 9364 73bd5012336f
permissions -rw-r--r--
[constraint] more robust unicity constraint failures reporting for end-users Postgres or Sqlserver have limits on the index names (around resp. 64 and 128 characters). Because `logilab.database` encodes the `unique together` constraint rtypes in the index names, we sometimes get truncated index names, from which it is impossible to retrieve all rtypes. In the long run, the way such index are named should be changed. In the short term, we try to reduce the end-user confusion resulting from this design flaw: * in source/native, the regex filtering ``IntegrityError`` message does not impose an `_idx` suffix, which indeed may be absent (the result being an UI message that resembles a catastrophic failure), * also we avoid including a trailing " (double quote) from the error message * in entities/adapters, the well-named ``IUserFriendly`` adapter is made a bit smarter about how to handle missing rtypes. * the adapter also always produces a global message explaining the issue (and the fact that sometimes, the user is not shown all the relevant info) * i18n is updated Closes #2793789

/* -*- sql -*-

   postgres specific registered procedures,
   require the plpgsql language installed

*/

DROP FUNCTION IF EXISTS comma_join (anyarray) CASCADE;
CREATE FUNCTION comma_join (anyarray) RETURNS text AS $$
    SELECT array_to_string($1, ', ')
$$ LANGUAGE SQL;;

DROP AGGREGATE IF EXISTS group_concat (anyelement) CASCADE;
CREATE AGGREGATE group_concat (
  basetype = anyelement,
  sfunc = array_append,
  stype = anyarray,
  finalfunc = comma_join,
  initcond = '{}'
);;



DROP FUNCTION IF EXISTS limit_size (fulltext text, format text, maxsize integer);
CREATE FUNCTION limit_size (fulltext text, format text, maxsize integer) RETURNS text AS $$
DECLARE
    plaintext text;
BEGIN
    IF char_length(fulltext) < maxsize THEN
       RETURN fulltext;
    END IF;
    IF format = 'text/html' OR format = 'text/xhtml' OR format = 'text/xml' THEN
       plaintext := regexp_replace(fulltext, '<[\\w/][^>]+>', '', 'g');
    ELSE
       plaintext := fulltext;
    END IF;
    IF char_length(plaintext) < maxsize THEN
       RETURN plaintext;
    ELSE
       RETURN substring(plaintext from 1 for maxsize) || '...';
    END IF;
END
$$ LANGUAGE plpgsql;;

DROP FUNCTION IF EXISTS text_limit_size (fulltext text, maxsize integer);
CREATE FUNCTION text_limit_size (fulltext text, maxsize integer) RETURNS text AS $$
BEGIN
    RETURN limit_size(fulltext, 'text/plain', maxsize);
END
$$ LANGUAGE plpgsql;;