|
| 1 | +CREATE FUNCTION plpgsql_check_custom(funcoid oid DEFAULT NULL::oid, warns boolean DEFAULT false, stop_fatal boolean DEFAULT true, msg_like text DEFAULT '%'::text, proname_regex text DEFAULT '^(.*)$'::text, schema_regex text DEFAULT '^(.*)$'::text) |
| 2 | + RETURNS TABLE(ts character, check_msg text) |
| 3 | + LANGUAGE plpgsql |
| 4 | +AS |
| 5 | +$$ |
| 6 | +DECLARE |
| 7 | + -- This cursor drives the process (plpgsql_check_function()) does all the work! |
| 8 | + -- The filters are simple enough to filter down the messages, or the procedure name, and to control the INTENSITY of the LINTING |
| 9 | + -- You get the source... Make it your own! I wanted something I could use flexibly |
| 10 | + msgs CURSOR (func oid, warnings boolean , fatals boolean) FOR SELECT * |
| 11 | + FROM (SELECT p.oid, |
| 12 | + p.prokind, |
| 13 | + n.nspname || '.' || p.proname || '()' AS proname, |
| 14 | + public.plpgsql_check_function( |
| 15 | + funcoid => p.oid::regproc |
| 16 | + , fatal_errors := fatals |
| 17 | + , extra_warnings := warnings |
| 18 | + , performance_warnings := warnings /* set these 3 to false for initial pass */ |
| 19 | + , all_warnings := warnings)::text AS err |
| 20 | + FROM pg_catalog.pg_namespace n |
| 21 | + JOIN pg_catalog.pg_proc p ON pronamespace = n.oid |
| 22 | + JOIN pg_catalog.pg_language l ON p.prolang = l.oid |
| 23 | + WHERE l.lanname = 'plpgsql' |
| 24 | + AND p.prorettype <> 2279 /* not a trigger */ |
| 25 | + AND n.nspname <> 'public' |
| 26 | + AND p.prokind IN ('p', 'f') -- Only function and procedures |
| 27 | + AND p.oid = COALESCE(func, p.oid) |
| 28 | + AND p.proname OPERATOR (pg_catalog.~) proname_regex |
| 29 | + AND n.nspname OPERATOR (pg_catalog.~) schema_regex) q1 |
| 30 | + WHERE q1.err LIKE msg_like; |
| 31 | + thisproc text := ''; -- Used so we only waste ONE line outputting what function we are working on, as opposed to a COLUMN |
| 32 | + errmsg text; -- The error message: "error:42883:42:assignment:function schem.function(integer, unknown, unknown, unknown, unknown, unknown, unknown) does not exist" |
| 33 | + a_txt text[]; -- Used to pars errmsg |
| 34 | + fdecl text; -- Declaration after parsing |
| 35 | + fname text; -- Before the parens |
| 36 | + foid oid; -- Function OID to lookup the named parameters |
| 37 | + parm1 text; -- between the parens |
| 38 | + pos INT; -- Simple position of ( for parsing |
| 39 | + a_p1 text[]; -- Array of Params from the users code |
| 40 | + has_in boolean; -- is IN/OUT present in any parameters |
| 41 | + names text; -- Function Signature with Parameter Names |
| 42 | + a_name text[]; -- string_to_aarray( names, ', ' ) -- [IN/OUT/INOUT] FLDNAME type [DEFAULT ...] |
| 43 | + a_pname text[]; -- Name ONLY of the field name |
| 44 | + n_off INT; -- Offset into the array for stuff |
| 45 | + str_out text; -- Messages to send out, with Chr(10) separating them! |
| 46 | + flow_def text; -- Should we default to IN all the time for flow |
| 47 | + flow text; -- IN/INOUT/OUT + DEF |
| 48 | +BEGIN |
| 49 | + ts := TO_CHAR(NOW(), 'HH24:MI:SS'); -- this is constant (Maybe a waste of the column, but forces a TABLE() return in case you want to add more columns, etc! |
| 50 | + FOR msg IN msgs(funcoid, warns, stop_fatal) |
| 51 | + LOOP |
| 52 | + str_out := ''; -- Start Fresh, and add strings as we go, for one final RETURN NEXT! |
| 53 | + IF thisproc <> msg.proname THEN -- Return a header! |
| 54 | + IF thisproc <> '' THEN |
| 55 | + check_msg := ''; |
| 56 | + RETURN NEXT; -- Blank line between different functions! |
| 57 | + END IF; |
| 58 | + thisproc := msg.proname; |
| 59 | + check_msg := CONCAT('===========> PROCESSING: ', thisproc); -- While REDUNDANT on 42883 Errors, it separates ALL functions from each other! |
| 60 | + RETURN NEXT; |
| 61 | + END IF; |
| 62 | + check_msg := msg.err; |
| 63 | + RETURN NEXT; |
| 64 | + errmsg := msg.err; |
| 65 | + IF errmsg LIKE 'error:42883:%' THEN |
| 66 | + -- SELECT '{}','{}','{}','{}','{}','{}' INTO a_txt, a_p1, a_p2, a_name, a_pname, a_flow; -- Produces plpgsql_check() warnings! |
| 67 | + a_txt := '{}'; |
| 68 | + a_p1 := '{}'; |
| 69 | + a_name := '{}'; |
| 70 | + a_pname := '{}'; |
| 71 | + |
| 72 | + str_out := '#### '; |
| 73 | + -- RETURN NEXT; |
| 74 | + IF RIGHT(errmsg, 14) = 'does not exist' THEN errmsg := LEFT(errmsg, -15); END IF; |
| 75 | + a_txt := STRING_TO_ARRAY(errmsg, ':'); |
| 76 | + IF CARDINALITY(a_txt) <> 5 THEN |
| 77 | + check_msg := str_out || chr(10) || '######## ==> details unavailable, parsing error <=== #########'::TEXT; |
| 78 | + RETURN NEXT; |
| 79 | + CONTINUE; |
| 80 | + END IF; |
| 81 | + fdecl := a_txt[5]; |
| 82 | + pos := POSITION('(' IN fdecl); |
| 83 | + IF pos = 0 THEN |
| 84 | + check_msg := str_out || chr(10) || '######## ==> details unavailable, parsing error(2) <=== #########'::TEXT; |
| 85 | + RETURN NEXT; |
| 86 | + CONTINUE; |
| 87 | + END IF; |
| 88 | + fname := LEFT(fdecl, pos - 1); -- exclude the paren |
| 89 | + fname := SUBSTR(fname, POSITION(' ' IN fname) + 1); |
| 90 | + parm1 := TRIM(SUBSTR(fdecl, pos, POSITION(')' IN fdecl) - pos + 1)); |
| 91 | + -- RETURN NEXT (ts , concat('#### ', fdecl )); -- Really Just Debug! |
| 92 | + BEGIN |
| 93 | + foid := TO_REGPROC(fname)::oid; -- This function will not throw an exception, just returns NULL |
| 94 | + -- REPLACES the error block |
| 95 | + IF foid IS NULL THEN |
| 96 | + check_msg := '#### Either No Such function or No Paramters!'; |
| 97 | + RETURN NEXT; |
| 98 | + CONTINUE; |
| 99 | + END IF; |
| 100 | + |
| 101 | + str_out := str_out || chr(10) || CONCAT('#### ', 'Error in: ', thisproc, ' at Line: ', a_txt[3], ' PARAMETER TYPING ISSUE?') || chr(10) || '#### '; |
| 102 | + a_p1 := STRING_TO_ARRAY(SUBSTRING(parm1, 2, LENGTH(parm1) - 2), ', '); -- These are just the types |
| 103 | + |
| 104 | + SELECT (POSITION('IN ' IN args) + POSITION('OUT ' IN args) )> 0 as tagged, args into has_in, names FROM |
| 105 | + (SELECT pg_catalog.PG_GET_FUNCTION_ARGUMENTS(foid) as args) t; |
| 106 | + |
| 107 | + a_name := STRING_TO_ARRAY(names, ', '); -- Separate these out! has_in is set for us |
| 108 | + |
| 109 | + /* We have an array of [INOUT] varname type [DEFAULT xxx] | And an array of the users param types param1 We will OUTPUT: |
| 110 | + Parameter Name [35], INOUT+DEF[10], P1_TYPE[15], OUR_TYPE \n */ |
| 111 | + str_out := CONCAT(str_out, chr(10), '#### ', rpad('Param Name',20), ' ', rpad('Flow/DEF',10), rpad('(your code)',15), rpad('Definition',15) ); |
| 112 | + str_out := CONCAT(str_out, chr(10), '#### ', rpad('==========',20), ' ', rpad('========',10), rpad('===========',15), rpad('==========',15) ); |
| 113 | + IF has_in THEN |
| 114 | + n_off := 1; |
| 115 | + flow_def := NULL; |
| 116 | + ELSE |
| 117 | + n_off := 0; |
| 118 | + flow_def := 'IN '; -- We have to force the display of IN, just for consistency. |
| 119 | + END IF; |
| 120 | + FOR x IN 1 .. CARDINALITY(a_name) |
| 121 | + LOOP |
| 122 | + a_pname := STRING_TO_ARRAY(a_name[x], ' '); -- Parse into an array |
| 123 | +-- RAISE NOTICE 'a_pname 1 %, 2 %, 3 %', a_pname[1], a_pname[2], a_pname[3]; |
| 124 | + flow := COALESCE(flow_def, a_pname[1]) || CASE WHEN POSITION('DEFAULT' IN a_name[x])=0 THEN '' ELSE ' DEF' END; |
| 125 | + str_out := CONCAT(str_out, chr(10), '#### ', rpad(a_pname[1+n_off],20), ' ',rpad(flow,10), rpad(coalesce(a_p1[x],'???'),15), rpad(a_pname[2+n_off],15) ); |
| 126 | + END LOOP; |
| 127 | + EXCEPTION |
| 128 | + WHEN OTHERS THEN |
| 129 | + str_out := str_out || chr(10) || CONCAT('==== ERROR: ', SQLERRM, ' Unexpected Exception!'); |
| 130 | + END; |
| 131 | + str_out := str_out || chr(10) || '#### '; |
| 132 | + ELSE |
| 133 | + CONTINUE; -- Nothing to do, not our message |
| 134 | + END IF; |
| 135 | + check_msg := str_out; |
| 136 | + RETURN NEXT; |
| 137 | + END LOOP; |
| 138 | + IF thisproc='' AND funcoid is not null THEN |
| 139 | + check_msg := 'No Messages Returned for: ' || funcoid::regproc; |
| 140 | + RETURN NEXT; |
| 141 | + END IF; |
| 142 | + RETURN; |
| 143 | +END |
| 144 | +$$; |
0 commit comments