FOUND could have a different behavior in Snowflake in some scenarios.
This is a deprecated version of the SnowConvert documentation, please visit the official site HERE.
Severity
Low
Description
The FOUND property in PostgreSQL is a property based on the last executed query, it can be affected by some statements such as INSERT, UPDATE, DELETE, MERGE, SELECT INTO, PERFORM, FETCH and FOR loops. To read more details about this property, this is PostgreSQL documentation.
In Snowflake there is not a direct translation for this property, for the following scenarios:
INSERT
UPDATE
DELETE
MERGE
The converted code will be SQLFOUND Snowflake property (Here is the documentation) since it behaves like the PostgreSQL FOUND property.
For the other cases such as:
SELECT INTO
PERFORM
FETCH
The converted code will be a custom UDF (IS_FOUND_UDF) that behaves like the PostgreSQL FOUND property.
This happens because SQLFOUND changes its value only when at least one row is affected by the last executed query, if the last query does not change any row, it does not change.
While the IS_FOUND_UDF only works for statements that returns rows, if no row is returned it, it will return FALSE.
SQLFOUND Example
INSERT INTO SampleTable (SampleColumn1)VALUES ('SampleValue0.1');
The last query affects a table, so the SQLFOUND is the closest to the PostgreSQL functionality.
IS_FOUND_UDF Example
SELECT SampleColumn FROM SampleTable;
The last query will return a row but does not change anything, so the IS_FOUND_UDF() is the closest to the PostgreSQL functionality.
IS_FOUND_UDF Source Code
CREATE OR REPLACE FUNCTION IS_FOUND_UDF() RETURNS BOOLEANLANGUAGE SQLIMMUTABLEAS$$ SELECT (COUNT(*) !=0) FROM TABLE(RESULT_SCAN(LAST_QUERY_ID()));$$;
Code Example
Insert Statement:
-- Found property used with INSERT statement.CREATE OR REPLACE FUNCTION FoundUsingInsertFunction()RETURNS BOOLEANAS$$ BEGIN INSERT INTO SampleTable (SampleColumn1)VALUES ('SampleValue0.1'); RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with INSERT statement.CREATE OR REPLACE PROCEDURE FoundUsingInsertFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ BEGIN INSERT INTO SampleTable (SampleColumn1)VALUES ('SampleValue0.1'); RETURN SQLFOUND /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Update Statement:
-- Found property used with UPDATE statement.CREATE OR REPLACE FUNCTION FoundUsingUpdateFunction()RETURNS BOOLEANAS$$ BEGIN UPDATE SampleTable SET SampleColumn1 ='SampleValue0.1' WHERE SampleColumn1 ='SampleValue0.1'; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with UPDATE statement.CREATE OR REPLACE PROCEDURE FoundUsingUpdateFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ BEGIN UPDATE SampleTable SET SampleColumn1 ='SampleValue0.1' WHERE SampleColumn1 ='SampleValue0.1'; RETURN SQLFOUND /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Delete Statement:
-- Found property used with DELETE statement.CREATE OR REPLACE FUNCTION FoundUsingDeleteFunction()RETURNS BOOLEANAS$$ BEGIN DELETE FROM SampleTable WHERE SampleColumn1 ='SampleValue0.1'; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with DELETE statement.CREATE OR REPLACE PROCEDURE FoundUsingDeleteFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ BEGIN DELETE FROM SampleTable WHERE SampleColumn1 ='SampleValue0.1'; RETURN SQLFOUND /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Merge Statement:
-- Found property used with MERGE statement.CREATE OR REPLACE FUNCTION FoundUsingMergeFunction()RETURNS BOOLEANAS$$ BEGIN MERGE INTO SampleTableB B USING (SELECT * FROM SampleTableA) AON B.SampleColumn1 = A.SampleColumn2 WHEN MATCHED THEN DELETE; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with MERGE statement.CREATE OR REPLACE PROCEDURE FoundUsingMergeFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ BEGIN MERGE INTO SampleTableB B USING (SELECT * FROM SampleTableA) AON B.SampleColum1 = A.SampleColum2 WHEN MATCHED THEN DELETE; RETURN SQLFOUND /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Select Into Statement
-- Found property used with SELECT INTO statement.CREATE OR REPLACE FUNCTION FoundUsingSelectIntoFunction()RETURNS BOOLEANAS$$ DECLARE SampleNumber INTEGER; BEGIN SELECT 1 INTO SampleNumber; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with SELECT INTO statement.CREATE OR REPLACE PROCEDURE FoundUsingSelectIntoFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ DECLARE SampleNumber INTEGER; BEGIN SELECT 1 INTO :SampleNumber; RETURN IS_FOUND_UDF() /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Perform Statement:
-- Found property used with PERFORM statement.CREATE OR REPLACE FUNCTION FoundUsingPerformFunction()RETURNS BOOLEANAS$$ BEGIN PERFORM 1; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with SELECT statement.CREATE OR REPLACE PROCEDURE FoundUsingSelectFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ BEGIN SELECT 1; RETURN IS_FOUND_UDF() /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;
Fetch Statement:
-- Found property used with FETCH statement.CREATE OR REPLACE FUNCTION FoundUsingFetchFunction ()RETURNS BOOLEANAS$$ DECLARE SampleRow VARCHAR; SampleCursor CURSOR FOR SELECT EmptyColumn FROM EmptyTable; BEGIN OPEN SampleCursor; FETCH SampleCursor; CLOSE SampleCursor; RETURN FOUND; END;$$LANGUAGE plpgsql;
-- Found property used with FETCH statement.CREATE OR REPLACE PROCEDURE FoundUsingFetchFunction ()RETURNS BOOLEANLANGUAGE SQLAS$$ DECLARE SampleRow VARCHAR; SampleCursor CURSOR FOR SELECT EmptyColumn FROM EmptyTable; BEGIN OPEN SampleCursor; FETCH SampleCursor; CLOSE SampleCursor; RETURN IS_FOUND_UDF() /*** MSC-WARNING - MSC-PG0027 - FOUND COULD HAVE A DIFFERENT BEHAVIOR IN SNOWFLAKE IN SOME SCENARIOS ***/; END;$$;