Skip to content

Commit

Permalink
Add sql migration scripts for 4.4.x
Browse files Browse the repository at this point in the history
  • Loading branch information
GeryNi committed Sep 30, 2024
1 parent cd18eb3 commit dc8c219
Show file tree
Hide file tree
Showing 2 changed files with 73 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
CREATE OR REPLACE FUNCTION url_utf8_percent_encode(input_string TEXT)
RETURNS TEXT LANGUAGE plpgsql AS
$$
DECLARE
result TEXT := '';
current_char TEXT;
hex_value TEXT;
ascii_value INT;
BEGIN
FOR i IN 1..LENGTH(input_string) LOOP
current_char := SUBSTRING(input_string FROM i FOR 1);

-- Get ASCII value of the current character
ascii_value := ASCII(current_char);

-- Check if the character is safe for URLs
IF ascii_value BETWEEN 48 AND 57 -- 0-9
OR ascii_value BETWEEN 65 AND 90 -- A-Z
OR ascii_value BETWEEN 97 AND 122 -- a-z
OR ascii_value IN (45, 46, 95, 126) -- '-', '.', '_', '~'
THEN
result := result || current_char;
ELSE
-- Convert the character to its byte representation in UTF-8
hex_value := ENCODE(CONVERT_TO(current_char, 'UTF8'), 'hex');

-- Percent-encode each byte of the UTF-8 encoded string
result := result || '%' || UPPER(SUBSTRING(hex_value, 1, 2));

-- If the character is multi-byte (more than one byte in UTF-8), append the rest
IF LENGTH(hex_value) > 2 THEN
FOR j IN 2..(LENGTH(hex_value) / 2) LOOP
result := result || '%' || UPPER(SUBSTRING(hex_value, (j * 2 - 1), 2));
END LOOP;
END IF;
END IF;
END LOOP;

RETURN result;
END
$$;
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@

WITH ns AS (select ARRAY [ARRAY ['xlink', 'http://www.w3.org/1999/xlink'],
ARRAY ['mdb', 'http://standards.iso.org/iso/19115/-3/mdb/2.0'],
ARRAY ['cit', 'http://standards.iso.org/iso/19115/-3/cit/2.0'],
ARRAY ['mri', 'http://standards.iso.org/iso/19115/-3/mri/1.0'],
ARRAY ['mco', 'http://standards.iso.org/iso/19115/-3/mco/1.0'],
ARRAY ['mrd', 'http://standards.iso.org/iso/19115/-3/mrd/1.0'],
ARRAY ['xsi', 'http://www.w3.org/2001/XMLSchema-instance'],
ARRAY ['gco', 'http://standards.iso.org/iso/19115/-3/gco/1.0']] AS n)
UPDATE metadata
SET data = REPLACE(data, aduLink, 'https://geoportail.wallonie.be/walonmap#PANIER=' || url_utf8_percent_encode(
'[{"serviceId":"1","visible":true,"url":"' || esriRest || '","label":' || to_json(currentTitle)::text ||
',"type":"AGS_DYNAMIC","metadataUrl":"https://geodata.wallonie.be/doc/' || currentId || '"}]'::text))
FROM (SELECT distinct(
unnest(xpath('//mdb:identificationInfo/*/mri:citation/*/cit:title/*/text()',
XMLPARSE(DOCUMENT data), n)))::text AS currentTitle,
data as currentXml,
uuid as currentId,
unnest(xpath('//mrd:onLine/*[cit:protocol/*/text() = ''ESRI:REST'']/cit:linkage/*/text()',
XMLPARSE(DOCUMENT data), n))::text AS esriRest,
unnest(xpath(
'//mrd:onLine/*/cit:linkage/*/text()[contains(., ''https://geoportail.wallonie.be/walonmap/#ADU'')]',
XMLPARSE(DOCUMENT data), n))::text AS aduLink,
unnest(xpath('//mdb:metadataScope/*/mdb:resourceScope/*/@codeListValue',
XMLPARSE(DOCUMENT data), n))::text AS resourceScope
FROM metadata,
ns
WHERE data LIKE '%https://geoportail.wallonie.be/walonmap/#ADU%'
ORDER BY uuid) AS records
WHERE resourceScope != 'service'
AND metadata.uuid = records.currentId
AND esriRest != '';

0 comments on commit dc8c219

Please sign in to comment.