a friend of mine (Gabriel Wyss) wrote this little scalar funktion for me in Microsoft SQL.
Since I use Postgres I tried to transform to Postgres syntax, but it did’nt work.
Can anybody please translate this little piece of code for me?
CREATE FUNCTION [dbo].[OrteListe]
( @haupt_id SYSNAME
)
RETURNS NVARCHAR(MAX)
If I read that code correctly the following line aggregates all the values into 1 string delimited with a comma. Am I right?
SELECT @s = COALESCE(@s + N', ', N'') + kind
Then the PostgreSQL variant of this would be the following (untested) function:
CREATE FUNCTION public.test(haupt_id character varying)
RETURNS character varying
LANGUAGE 'plpgsql'
AS $BODY$
DECLARE result VARCHAR;
BEGIN
SELECT string_agg(kind ,',') INTO result
FROM kind
WHERE haupt_id = $1
ORDER BY kind;
RETURN result;
END
$BODY$;
This does require you have plpgsql installed in the schema where the function is.
Of not you can install it using the following command:
CREATE EXTENSION plpgsql;
If it has to be in schema other than the default ‘PUBLIC’ then use this:
I ran a quick test on my SQL code and it turns out that the ORDER BY requires a GROUP BY then. But doing so you don’t get the result you want.
So the SQL should be like this:
WITH orderedvalues AS(
SELECT kind
FROM kind
WHERE haunt_id = $1
ORDER BY kind
)
SELECT string_agg(kind ,', ')
FROM orderedvalues
So the function would look like this:
CREATE FUNCTION public.test(haupt_id character varying)
RETURNS character varying
LANGUAGE 'plpgsql'
AS $BODY$
DECLARE result VARCHAR;
BEGIN
WITH orderedvalues AS (
SELECT kind
FROM kind
WHERE haunt_id = $1
ORDER BY kind
)
SELECT string_agg(kind ,', ') INTO result
FROM orderedvalues;
RETURN result;
END
$BODY$;