Good morning, this is a very insightful comment (among many) by you, David -
On Wed, May 4, 2022 at 5:40 PM David G. Johnston <david.g.johns...@gmail.com> wrote: > Well, that is basically why I was going on about the oddity of having > social be a part of the main query. Personally I would write it as > "myself.uid = in_uid", but you don't have an in_uid to reference. Decide > how you want to do something equivalent. > > so I will rewrite the stored functions in my game to be like that, to separate auth from functionality - https://dbfiddle.uk/?rdbms=postgres_14&fiddle=dbdf1a6b82f7232be45e23b8139a8f0e CREATE OR REPLACE FUNCTION words_get_uid( in_social integer, in_sid text ) RETURNS integer AS $func$ SELECT uid FROM words_social WHERE social = in_social AND sid = in_sid; $func$ LANGUAGE sql IMMUTABLE; CREATE OR REPLACE FUNCTION words_get_chat( in_gid integer, in_uid integer ) RETURNS TABLE ( out_mine integer, out_msg text ) AS $func$ SELECT CASE WHEN c.uid = in_uid THEN 1 ELSE 0 END, c.msg FROM words_chat c JOIN words_games g USING (gid) JOIN words_users opponent ON (opponent.uid IN (g.player1, g.player2) AND opponent.uid <> in_uid) WHERE c.gid = in_gid -- always show myself my own chat messages AND c.uid = in_uid -- otherwise only show messages by not muted opponents OR NOT opponent.muted ORDER BY c.created ASC; $func$ LANGUAGE sql; SELECT words_get_chat(10, words_get_uid(100, 'abc')) AS nice_user; SELECT words_get_chat(10, words_get_uid(200, 'def')) AS muted_user; Thanks Alex