I have found that the problem is worst. In the sample adjunct, you can see that error arise at the time when the view's sql text is parsed and saved in database catalog. Then generic NUMERIC type is forced for every calculated column without regard or precision. And at execute time the f2 column has varying type decimals (in row 2 you can see 4 decimals and in other rows has 3 decimals), this is not a behavior , this is an ERROR. Precision calculation in Numeric fields it's not so difficult. This problem *must* be corrected in the CREATE VIEW sentence , and I offer my collaboration for that. Regards all, Dario Fassi. Dario V. Fassi wrote:
|
CREATE TABLE public.t ( f1 numeric(6,3), f2 numeric(6,4), f3 numeric(8,2) ) WITHOUT OIDS; insert into public.t values ( 123.123, 12.1234, 12345.12); insert into public.t values ( null, 12.1234, 12345.12); insert into public.t values ( 123.123, null, 12345.12); insert into public.t values ( 123.123, 12.1234, null); -- -- Create sql text -- create view public v as select (f1+f2+f3) as fsum, coalesce(f1,f2,f3) as fcoal, (f1*f2*f3) as fprod from public.t; -- -- Parsed sql view from catalog -- CREATE OR REPLACE VIEW public.v AS SELECT ((t.f1 + t.f2 ) + t.f3 ) AS fsum, CASE WHEN (t.f1 IS NOT NULL ) THEN t.f1 WHEN (t.f2 IS NOT NULL ) THEN t.f2 WHEN (t.f3 IS NOT NULL ) THEN t.f3 ELSE NULL::numeric END AS fcoal, ((t.f1 * t.f2 ) * t.f3 ) AS fprod FROM t; -- -- Returned Data -- select * from public.v; fsum fcoal fprod 12480.3664 123.123 18427182.594204384 null 12.1234 null << !!! No look good !!! null 123.123 null null 123.123 null -- -- -- WORKAROUND WORKAROUND WORKAROUND -- -- -- -- Create sql text with forced datatype -- create view public v2 as select cast( (f1+f2+f3) as dec(9,4) ) as fsum, cast( coalesce(f1,f2,f3) as dec(7,4) ) as fcoal, cast( (f1*f2*f3) as dec(20,9) ) as fprod from public.t; -- -- Parsed sql view from catalog -- CREATE OR REPLACE VIEW public.v2 AS SELECT (((t.f1 + t.f2 ) + t.f3))::numeric(9,4 ) AS fsum, ( CASE WHEN (t.f1 IS NOT NULL ) THEN t.f1 WHEN (t.f2 IS NOT NULL ) THEN t.f2 WHEN (t.f3 IS NOT NULL ) THEN t.f3 ELSE NULL::numeric END)::numeric(7,4 ) AS fcoal, (((t.f1 * t.f2 ) * t.f3))::numeric(20,9 ) AS fprod FROM t; -- -- Returned Data -- select * from public.v2; fsum fcoal fprod 12480.3664 123.1230 18427182.594204384 null 12.1234 null << It's ok now null 123.1230 null null 123.1230 null
---------------------------(end of broadcast)--------------------------- TIP 8: explain analyze is your friend