diff --git a/Functions/get_name_pg_int8_.txt b/Functions/get_name_pg_int8_.txt new file mode 100644 index 0000000000000000000000000000000000000000..f3cc20975db4be7fce32286f133fd12dc152bf01 --- /dev/null +++ b/Functions/get_name_pg_int8_.txt @@ -0,0 +1,84 @@ +-- DROP FUNCTION schema_xyz.get_name_pg(int8); + +CREATE OR REPLACE FUNCTION schema_xyz.get_name_pg(my_uid_ bigint) + RETURNS character varying + LANGUAGE plpgsql +AS $function$ + DECLARE + + +ergebnis varchar; +min_hi_date timestamp; +max_hi_date timestamp; +anz_namen bigint; +anz_namen_II bigint; + + +BEGIN + + +/* +We are looking for a name with a maximum first_date. If there is more than one, just take one... +*/ +select count(distinct name_d) into anz_namen from schema_xyz.u_name where uid_=my_uid_; + +IF (anz_namen=1) +THEN +select distinct(name_d) into ergebnis from schema_xyz.u_name where uid_=my_uid_; + +ELSE + +ergebnis:=null; + +select min(first_date) into min_hi_date from schema_xyz.relation where uid_1=my_uid_ and uid_0=0; +select max(last_date) into max_hi_date from schema_xyz.relation where uid_1=my_uid_ and uid_0=0; + +select count(name_d) into anz_namen_II +from schema_xyz.u_name +where uid_=my_uid_ +and first_date=(SELECT max(first_date) from schema_xyz.u_name where uid_=my_uid_ and first_date>=min_hi_date and last_date<=max_hi_date); + +if (anz_namen_II>0) +then +select name_d into ergebnis +from +(SELECT name_d +from schema_xyz.u_name +where uid_=my_uid_ +and first_date=(select max(first_date) from schema_xyz.u_name where uid_=my_uid_ and first_date>=min_hi_date and last_date<=max_hi_date)) alias3 LIMIT 1; +end if; + + +-- if nothing is found in this way, you can still search for a name that completely covers the HI time +if (ergebnis is null) +then + +select name_d into ergebnis +from (SELECT name_d +from schema_xyz.u_name +where uid_=my_uid_ +and first_date<=min_hi_date and last_date >= max_hi_date) alias1 LIMIT 1; + +end if; + +-- Then there are still those with a name change in the middle. Simply add names with a maximum last_date and you're done. +if (ergebnis is null) +then + +select name_d into ergebnis +from +(SELECT name_d +from schema_xyz.u_name +where uid_=my_uid_ +and last_date=(select max(last_date) from schema_xyz.u_name where uid_=my_uid_)) alias3 LIMIT 1; + +end if; + +end if; + +RETURN ergebnis; + + +END; + $function$ +;