Skip to content

Instantly share code, notes, and snippets.

@samuelhorwitz
Last active October 26, 2017 18:46
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save samuelhorwitz/0bc77a517238914512fc8cdf50d217cd to your computer and use it in GitHub Desktop.
Save samuelhorwitz/0bc77a517238914512fc8cdf50d217cd to your computer and use it in GitHub Desktop.
JSON building/stored procedure/view indirection segmentation fault affecting Postgres 9 and 10
ALTER TABLE base_table ADD COLUMN new_column boolean NOT NULL DEFAULT false;
CREATE OR REPLACE VIEW base_table_view AS SELECT base_table.*
FROM base_table;
CREATE OR REPLACE FUNCTION get_base_table_json(el anyelement) RETURNS json
LANGUAGE plpgsql
AS $$ BEGIN
RETURN json_build_object(
'id', el.id,
'newVal', el.new_column,
'value', el.some_json
);
END; $$;
CREATE OR REPLACE VIEW base_table_json AS
SELECT base_table_view.id,
get_base_table_json(base_table_view.*) AS json
FROM base_table_view;
--
-- PostgreSQL database dump
--
-- Dumped from database version 9.6.5
-- Dumped by pg_dump version 9.6.3
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SET check_function_bodies = false;
SET client_min_messages = warning;
SET row_security = off;
CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
SET search_path = public, pg_catalog;
CREATE FUNCTION get_base_table_json(el anyelement) RETURNS json
LANGUAGE plpgsql
AS $$ BEGIN
RETURN json_build_object(
'id', el.id,
'value', el.some_json
);
END; $$;
SET default_tablespace = '';
SET default_with_oids = false;
CREATE TABLE base_table (
id bigint NOT NULL,
some_json jsonb
);
CREATE SEQUENCE base_table_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER SEQUENCE base_table_id_seq OWNED BY base_table.id;
CREATE VIEW base_table_view AS
SELECT base_table.id,
base_table.some_json
FROM base_table;
CREATE VIEW base_table_json AS
SELECT base_table_view.id,
get_base_table_json(base_table_view.*) AS json
FROM base_table_view;
ALTER TABLE ONLY base_table ALTER COLUMN id SET DEFAULT nextval('base_table_id_seq'::regclass);
INSERT INTO base_table VALUES (24885, '{"foo": "bar"}');
SELECT pg_catalog.setval('base_table_id_seq', 1, false);
@samuelhorwitz
Copy link
Author

How to reproduce

  1. Create a new database.
  2. Execute initial.sql
  3. Run SELECT id, json FROM base_table_json and observe the result being correctly returned.
  4. Execute break-it.sql
  5. Run SELECT id, json FROM base_table_json and observe the segmentation fault occur.
  6. Execute fix-it.sql
  7. Run SELECT id, json FROM base_table_json and observe everything working again.

Note that fix-it.sql does nothing except recreates the view exactly as it was before (but likely flushing out some cache or something behind the scenes in doing so).

Sample log of expected failure:

LOG:  00000: server process (PID 26) was terminated by signal 11: Segmentation fault
DETAIL:  Failed process was running: SELECT "id", "json" FROM "public"."base_table_json"    LIMIT 1000
LOCATION:  LogChildExit, postmaster.c:3526
LOG:  00000: terminating any other active server processes
LOCATION:  HandleChildCrash, postmaster.c:3246
WARNING:  57P02: terminating connection because of crash of another server process
DETAIL:  The postmaster has commanded this server process to roll back the current transaction and exit, because another server process exited abnormally and possibly corrupted shared memory.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment