├── .dockerignore ├── .github ├── ISSUE_TEMPLATE │ ├── bug_report.md │ └── rfc.md └── workflows │ └── test.yaml ├── .gitignore ├── .pre-commit-config.yaml ├── LICENSE ├── README.md ├── bin └── installcheck ├── sql ├── setup.sql ├── walrus--0.1.sql ├── walrus_migration_0001_support_wal2json_2_4.sql ├── walrus_migration_0002_filter_handle_nulls.sql ├── walrus_migration_0003_delete_filters_bugfix.sql ├── walrus_migration_0004_in_op.sql ├── walrus_migration_0005_delete_old_record_rls.sql ├── walrus_migration_0006_high_res_commit_timestamp.sql ├── walrus_migration_0007_commit_timestamp_utc.sql ├── walrus_migration_0008_subscription_check_array_types.sql ├── walrus_migration_0009_unchanged_toast.sql ├── walrus_migration_0010_quoted_roles.sql └── walrus_migration_0011_delete_filters.sql └── test ├── expected ├── issue_40_quoted_regtype.out ├── issue_50_delete_filters.out ├── issue_55_null_passes_filters.out ├── test_column_permissions_hide_columns.out ├── test_delete_old_record_behavior.out ├── test_error_no_primary_key.out ├── test_error_payload_too_large.out ├── test_error_unauthorized.out ├── test_integration_filters.out ├── test_integration_in_filter.out ├── test_integration_in_uuid_filter.out ├── test_non_public_schema.out ├── test_old_record_is_primary_key.out ├── test_old_record_replica_identity_full.out ├── test_query_from_publication.out ├── test_rls_skips_subscriber.out ├── test_role_with_hyphen.out ├── test_select_one.out ├── test_simple_delete.out ├── test_simple_insert.out ├── test_simple_update.out ├── test_subscribers_multiple_roles.out ├── test_unchanged_toast.out ├── test_unit_filters.out └── test_wal2json_output.out ├── fixtures.sql └── sql ├── issue_40_quoted_regtype.sql ├── issue_50_delete_filters.sql ├── issue_55_null_passes_filters.sql ├── test_column_permissions_hide_columns.sql ├── test_delete_old_record_behavior.sql ├── test_error_no_primary_key.sql ├── test_error_payload_too_large.sql ├── test_error_unauthorized.sql ├── test_integration_filters.sql ├── test_integration_in_filter.sql ├── test_integration_in_uuid_filter.sql ├── test_non_public_schema.sql ├── test_old_record_is_primary_key.sql ├── test_old_record_replica_identity_full.sql ├── test_query_from_publication.sql ├── test_rls_skips_subscriber.sql ├── test_role_with_hyphen.sql ├── test_select_one.sql ├── test_simple_delete.sql ├── test_simple_insert.sql ├── test_simple_update.sql ├── test_subscribers_multiple_roles.sql ├── test_unchanged_toast.sql ├── test_unit_filters.sql └── test_wal2json_output.sql /.dockerignore: -------------------------------------------------------------------------------- 1 | .python-version 2 | .gitignore 3 | .clang-format 4 | README.md 5 | setup.py 6 | 7 | .benchmarks 8 | .git/ 9 | .github/ 10 | .pytest_cache/ 11 | assets/ 12 | docs/ 13 | wal_rls.egg-info/ 14 | site/ 15 | venv/ 16 | 17 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Create a report to help us improve 4 | title: '' 5 | labels: triage-required 6 | assignees: olirice 7 | 8 | --- 9 | 10 | **Describe the bug** 11 | A clear and concise description of what the bug is. 12 | 13 | **To Reproduce** 14 | Steps to reproduce the behavior: 15 | 1. 16 | 2. 17 | 3. 18 | 4. 19 | 20 | **Expected behavior** 21 | A clear and concise description of what you expected to happen. 22 | 23 | **Screenshots** 24 | If applicable, add screenshots to help explain your problem. 25 | 26 | **Desktop (please complete the following information):** 27 | - PostgreSQL: [e.g. 13.1] 28 | 29 | **Additional context** 30 | Add any other context about the problem here. 31 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/rfc.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: RFC 3 | about: Request for Comment 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | 8 | --- 9 | 10 | # Summary 11 | [summary]: #summary 12 | 13 | Short explanation of the feature. 14 | 15 | # Rationale 16 | [rationale]: #rationale 17 | 18 | Why should we do this? 19 | 20 | # Design 21 | [design]: #design 22 | 23 | An dense explanation in sufficient detail that someone familiar with the 24 | project could implement the feature. Specifics and corner cases should be covered. 25 | 26 | # Examples 27 | [examples]: #examples 28 | 29 | Illustrations and examples to clarify descriptions from previous sections. 30 | 31 | # Drawbacks 32 | [drawbacks]: #drawbacks 33 | 34 | What are the negative trade-offs? 35 | 36 | # Alternatives 37 | [alternatives]: #alternatives 38 | 39 | What other solutions have been considered? 40 | 41 | # Unresolved Questions 42 | [unresolved]: #unresolved-questions 43 | 44 | What parts of problem space or proposed designs are unknown or TBD? 45 | -------------------------------------------------------------------------------- /.github/workflows/test.yaml: -------------------------------------------------------------------------------- 1 | name: WALRUS tests 2 | 3 | on: 4 | pull_request: 5 | branches: [master] 6 | push: 7 | branches: [master] 8 | 9 | jobs: 10 | autotests: 11 | name: Run tests 12 | 13 | runs-on: ubuntu-latest 14 | container: 15 | image: supabase/postgres:15.1.1.79 16 | options: --tmpfs=/pgtmpfs -e PGDATA=/pgtmpfs 17 | 18 | steps: 19 | - uses: actions/checkout@v3 20 | 21 | - name: Checkout wal2json 22 | uses: actions/checkout@v3 23 | with: 24 | repository: eulerto/wal2json 25 | ref: master 26 | path: ./wal2json 27 | 28 | - name: Run Test 29 | run: | 30 | # install wal2json 31 | cd wal2json 32 | apt-get update && apt-get install build-essential llvm-11 -y 33 | apt install -y wget lsb-release 34 | sh -c 'echo "deb http://apt.postgresql.org/pub/repos/apt $(lsb_release -cs)-pgdg main" > /etc/apt/sources.list.d/pgdg.list' 35 | wget --quiet -O - https://www.postgresql.org/media/keys/ACCC4CF8.asc | apt-key add - 36 | apt-get update 37 | apt install libpq5=16.3-1.pgdg20.04+1 libpq-dev postgresql-server-dev-15 -y --allow-downgrades 38 | 39 | make 40 | make install 41 | # run tests 42 | cd .. 43 | chown -R postgres /__w/walrus/walrus 44 | su postgres -c 'export PATH=$PATH:/usr/lib/postgresql/15/bin/ ; bin/installcheck' 45 | 46 | - uses: actions/upload-artifact@v3 47 | if: always() 48 | with: 49 | name: regression.out 50 | path: regression.out 51 | retention-days: 7 52 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | results/ 2 | .python-version 3 | venv/ 4 | site/ 5 | regression.* 6 | __pycache__/ 7 | *.egg-info/ 8 | *.swp 9 | -------------------------------------------------------------------------------- /.pre-commit-config.yaml: -------------------------------------------------------------------------------- 1 | repos: 2 | - repo: https://github.com/pre-commit/pre-commit-hooks 3 | rev: v4.0.1 4 | hooks: 5 | - id: trailing-whitespace 6 | exclude: ^test/expected 7 | - id: check-yaml 8 | - id: check-merge-conflict 9 | - id: check-added-large-files 10 | args: ['--maxkb=500'] 11 | - id: mixed-line-ending 12 | args: ['--fix=lf'] 13 | 14 | - repo: https://github.com/Lucas-C/pre-commit-hooks 15 | rev: v1.1.10 16 | hooks: 17 | - id: remove-tabs 18 | name: Tabs-to-Spaces 19 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | Copyright 2021 Supabase 179 | 180 | Licensed under the Apache License, Version 2.0 (the "License"); 181 | you may not use this file except in compliance with the License. 182 | You may obtain a copy of the License at 183 | 184 | http://www.apache.org/licenses/LICENSE-2.0 185 | 186 | Unless required by applicable law or agreed to in writing, software 187 | distributed under the License is distributed on an "AS IS" BASIS, 188 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 189 | See the License for the specific language governing permissions and 190 | limitations under the License. 191 | -------------------------------------------------------------------------------- /bin/installcheck: -------------------------------------------------------------------------------- 1 | #! /bin/bash 2 | 3 | ######## 4 | # Vars # 5 | ######## 6 | TMPDIR="$(mktemp -d)" 7 | export PGDATA="$TMPDIR" 8 | export PGHOST="$TMPDIR" 9 | export PGUSER=postgres 10 | export PGDATABASE=postgres 11 | export PGTZ=UTC 12 | export PG_COLOR=auto 13 | 14 | #################### 15 | # Ensure Clean Env # 16 | #################### 17 | # Stop the server (if running) 18 | trap 'pg_ctl stop -m i' sigint sigterm exit 19 | # Remove temporary data dir 20 | rm -rf "$tmpdir" 21 | 22 | ############## 23 | # Initialize # 24 | ############## 25 | 26 | # Initialize: setting PGUSER as the owner 27 | initdb --no-locale --encoding=UTF8 --nosync -U "$PGUSER" 28 | # Start the server 29 | pg_ctl start -o "-F -c wal_level=logical -c fsync=off -c listen_addresses=\"\" -c log_min_messages=FATAL -k $PGDATA" 30 | # Start the server 31 | createdb contrib_regression 32 | 33 | ######### 34 | # Tests # 35 | ######### 36 | TESTDIR="test" 37 | PGXS=$(dirname `pg_config --pgxs`) 38 | REGRESS="${PGXS}/../test/regress/pg_regress" 39 | 40 | # Collect Test List 41 | TESTS=$(ls ${TESTDIR}/sql | sed -e 's/\..*$//' | sort ) 42 | 43 | # Execute the test fixtures 44 | psql -v ON_ERROR_STOP=1 -f sql/setup.sql -f sql/walrus--0.1.sql -f sql/walrus_migration_0001*.sql -f sql/walrus_migration_0002*.sql -f sql/walrus_migration_0003*.sql -f sql/walrus_migration_0004*.sql -f sql/walrus_migration_0005*.sql -f sql/walrus_migration_0006*.sql -f sql/walrus_migration_0007*.sql -f sql/walrus_migration_0008*.sql -f sql/walrus_migration_0009*.sql -f sql/walrus_migration_0010*.sql -f sql/walrus_migration_0011*.sql -f test/fixtures.sql -d contrib_regression 45 | 46 | # Run tests 47 | ${REGRESS} --use-existing --dbname=contrib_regression --inputdir=${TESTDIR} ${TESTS} 48 | -------------------------------------------------------------------------------- /sql/setup.sql: -------------------------------------------------------------------------------- 1 | /* 2 | SETUP 3 | */ 4 | -- Set up Realtime 5 | create publication supabase_realtime for all tables; 6 | 7 | -- Extension namespacing 8 | create schema extensions; 9 | create extension if not exists "uuid-ossp" with schema extensions; 10 | 11 | -- Developer role 12 | create role authenticated nologin noinherit; -- "logged in" user: web_user, app_user, etc 13 | 14 | grant usage on schema public to authenticated; 15 | alter default privileges in schema public grant all on tables to authenticated; 16 | alter default privileges in schema public grant all on functions to authenticated; 17 | alter default privileges in schema public grant all on sequences to authenticated; 18 | 19 | CREATE SCHEMA IF NOT EXISTS auth; 20 | 21 | -- Gets the User ID from the request cookie 22 | create or replace function auth.uid() returns uuid as $$ 23 | select 24 | coalesce( 25 | current_setting('request.jwt.claim.sub', true), 26 | current_setting('request.jwt.claims', true)::jsonb ->> 'sub' 27 | )::uuid; 28 | $$ language sql stable; 29 | -- Gets the User Role from the request cookie 30 | create or replace function auth.role() returns text as $$ 31 | select 32 | coalesce( 33 | current_setting('request.jwt.claim.role', true), 34 | current_setting('request.jwt.claims', true)::jsonb ->> 'role' 35 | )::text; 36 | $$ language sql stable; 37 | 38 | -- Gets the User Email from the request cookie 39 | create or replace function auth.email() returns text as $$ 40 | select 41 | coalesce( 42 | current_setting('request.jwt.claim.email', true), 43 | current_setting('request.jwt.claims', true)::jsonb ->> 'email' 44 | )::text; 45 | $$ language sql stable; 46 | 47 | ALTER ROLE postgres SET search_path = "$user", public, auth; 48 | 49 | GRANT USAGE ON SCHEMA auth TO authenticated; 50 | -------------------------------------------------------------------------------- /sql/walrus_migration_0002_filter_handle_nulls.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.is_visible_through_filters(columns realtime.wal_column[], filters realtime.user_defined_filter[]) 2 | returns bool 3 | language sql 4 | immutable 5 | as $$ 6 | /* 7 | Should the record be visible (true) or filtered out (false) after *filters* are applied 8 | */ 9 | select 10 | -- Default to allowed when no filters present 11 | $2 is null -- no filters. this should not happen because subscriptions has a default 12 | or array_length($2, 1) is null -- array length of an empty array is null... wtf 13 | or bool_and( 14 | coalesce( 15 | realtime.check_equality_op( 16 | op:=f.op, 17 | type_:=coalesce( 18 | col.type_oid::regtype, -- null when wal2json version <= 2.4 19 | col.type_name::regtype 20 | ), 21 | -- cast jsonb to text 22 | val_1:=col.value #>> '{}', 23 | val_2:=f.value 24 | ), 25 | false -- if null, filter does not match 26 | ) 27 | ) 28 | from 29 | unnest(filters) f 30 | join unnest(columns) col 31 | on f.column_name = col.name; 32 | $$; 33 | -------------------------------------------------------------------------------- /sql/walrus_migration_0003_delete_filters_bugfix.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.apply_rls(wal jsonb, max_record_bytes int = 1024 * 1024) 2 | returns setof realtime.wal_rls 3 | language plpgsql 4 | volatile 5 | as $$ 6 | declare 7 | -- Regclass of the table e.g. public.notes 8 | entity_ regclass = (quote_ident(wal ->> 'schema') || '.' || quote_ident(wal ->> 'table'))::regclass; 9 | 10 | -- I, U, D, T: insert, update ... 11 | action realtime.action = ( 12 | case wal ->> 'action' 13 | when 'I' then 'INSERT' 14 | when 'U' then 'UPDATE' 15 | when 'D' then 'DELETE' 16 | else 'ERROR' 17 | end 18 | ); 19 | 20 | -- Is row level security enabled for the table 21 | is_rls_enabled bool = relrowsecurity from pg_class where oid = entity_; 22 | 23 | subscriptions realtime.subscription[] = array_agg(subs) 24 | from 25 | realtime.subscription subs 26 | where 27 | subs.entity = entity_; 28 | 29 | -- Subscription vars 30 | roles regrole[] = array_agg(distinct us.claims_role) 31 | from 32 | unnest(subscriptions) us; 33 | 34 | working_role regrole; 35 | claimed_role regrole; 36 | claims jsonb; 37 | 38 | subscription_id uuid; 39 | subscription_has_access bool; 40 | visible_to_subscription_ids uuid[] = '{}'; 41 | 42 | -- structured info for wal's columns 43 | columns realtime.wal_column[]; 44 | -- previous identity values for update/delete 45 | old_columns realtime.wal_column[]; 46 | 47 | error_record_exceeds_max_size boolean = octet_length(wal::text) > max_record_bytes; 48 | 49 | -- Primary jsonb output for record 50 | output jsonb; 51 | 52 | begin 53 | perform set_config('role', null, true); 54 | 55 | columns = 56 | array_agg( 57 | ( 58 | x->>'name', 59 | x->>'type', 60 | x->>'typeoid', 61 | realtime.cast( 62 | (x->'value') #>> '{}', 63 | coalesce( 64 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 65 | (x->>'type')::regtype 66 | ) 67 | ), 68 | (pks ->> 'name') is not null, 69 | true 70 | )::realtime.wal_column 71 | ) 72 | from 73 | jsonb_array_elements(wal -> 'columns') x 74 | left join jsonb_array_elements(wal -> 'pk') pks 75 | on (x ->> 'name') = (pks ->> 'name'); 76 | 77 | old_columns = 78 | array_agg( 79 | ( 80 | x->>'name', 81 | x->>'type', 82 | x->>'typeoid', 83 | realtime.cast( 84 | (x->'value') #>> '{}', 85 | coalesce( 86 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 87 | (x->>'type')::regtype 88 | ) 89 | ), 90 | (pks ->> 'name') is not null, 91 | true 92 | )::realtime.wal_column 93 | ) 94 | from 95 | jsonb_array_elements(wal -> 'identity') x 96 | left join jsonb_array_elements(wal -> 'pk') pks 97 | on (x ->> 'name') = (pks ->> 'name'); 98 | 99 | for working_role in select * from unnest(roles) loop 100 | 101 | -- Update `is_selectable` for columns and old_columns 102 | columns = 103 | array_agg( 104 | ( 105 | c.name, 106 | c.type_name, 107 | c.type_oid, 108 | c.value, 109 | c.is_pkey, 110 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 111 | )::realtime.wal_column 112 | ) 113 | from 114 | unnest(columns) c; 115 | 116 | old_columns = 117 | array_agg( 118 | ( 119 | c.name, 120 | c.type_name, 121 | c.type_oid, 122 | c.value, 123 | c.is_pkey, 124 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 125 | )::realtime.wal_column 126 | ) 127 | from 128 | unnest(old_columns) c; 129 | 130 | if action <> 'DELETE' and count(1) = 0 from unnest(columns) c where c.is_pkey then 131 | return next ( 132 | jsonb_build_object( 133 | 'schema', wal ->> 'schema', 134 | 'table', wal ->> 'table', 135 | 'type', action 136 | ), 137 | is_rls_enabled, 138 | -- subscriptions is already filtered by entity 139 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 140 | array['Error 400: Bad Request, no primary key'] 141 | )::realtime.wal_rls; 142 | 143 | -- The claims role does not have SELECT permission to the primary key of entity 144 | elsif action <> 'DELETE' and sum(c.is_selectable::int) <> count(1) from unnest(columns) c where c.is_pkey then 145 | return next ( 146 | jsonb_build_object( 147 | 'schema', wal ->> 'schema', 148 | 'table', wal ->> 'table', 149 | 'type', action 150 | ), 151 | is_rls_enabled, 152 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 153 | array['Error 401: Unauthorized'] 154 | )::realtime.wal_rls; 155 | 156 | else 157 | output = jsonb_build_object( 158 | 'schema', wal ->> 'schema', 159 | 'table', wal ->> 'table', 160 | 'type', action, 161 | 'commit_timestamp', to_char( 162 | (wal ->> 'timestamp')::timestamptz, 163 | 'YYYY-MM-DD"T"HH24:MI:SS"Z"' 164 | ), 165 | 'columns', ( 166 | select 167 | jsonb_agg( 168 | jsonb_build_object( 169 | 'name', pa.attname, 170 | 'type', pt.typname 171 | ) 172 | order by pa.attnum asc 173 | ) 174 | from 175 | pg_attribute pa 176 | join pg_type pt 177 | on pa.atttypid = pt.oid 178 | where 179 | attrelid = entity_ 180 | and attnum > 0 181 | and pg_catalog.has_column_privilege(working_role, entity_, pa.attname, 'SELECT') 182 | ) 183 | ) 184 | -- Add "record" key for insert and update 185 | || case 186 | when action in ('INSERT', 'UPDATE') then 187 | case 188 | when error_record_exceeds_max_size then 189 | jsonb_build_object( 190 | 'record', 191 | ( 192 | select jsonb_object_agg((c).name, (c).value) 193 | from unnest(columns) c 194 | where (c).is_selectable and (octet_length((c).value::text) <= 64) 195 | ) 196 | ) 197 | else 198 | jsonb_build_object( 199 | 'record', 200 | (select jsonb_object_agg((c).name, (c).value) from unnest(columns) c where (c).is_selectable) 201 | ) 202 | end 203 | else '{}'::jsonb 204 | end 205 | -- Add "old_record" key for update and delete 206 | || case 207 | when action in ('UPDATE', 'DELETE') then 208 | case 209 | when error_record_exceeds_max_size then 210 | jsonb_build_object( 211 | 'old_record', 212 | ( 213 | select jsonb_object_agg((c).name, (c).value) 214 | from unnest(old_columns) c 215 | where (c).is_selectable and (octet_length((c).value::text) <= 64) 216 | ) 217 | ) 218 | else 219 | jsonb_build_object( 220 | 'old_record', 221 | (select jsonb_object_agg((c).name, (c).value) from unnest(old_columns) c where (c).is_selectable) 222 | ) 223 | end 224 | else '{}'::jsonb 225 | end; 226 | 227 | -- Create the prepared statement 228 | if is_rls_enabled and action <> 'DELETE' then 229 | if (select 1 from pg_prepared_statements where name = 'walrus_rls_stmt' limit 1) > 0 then 230 | deallocate walrus_rls_stmt; 231 | end if; 232 | execute realtime.build_prepared_statement_sql('walrus_rls_stmt', entity_, columns); 233 | end if; 234 | 235 | visible_to_subscription_ids = '{}'; 236 | 237 | for subscription_id, claims in ( 238 | select 239 | subs.subscription_id, 240 | subs.claims 241 | from 242 | unnest(subscriptions) subs 243 | where 244 | subs.entity = entity_ 245 | and subs.claims_role = working_role 246 | and ( 247 | realtime.is_visible_through_filters(columns, subs.filters) 248 | or action = 'DELETE' 249 | ) 250 | ) loop 251 | 252 | if not is_rls_enabled or action = 'DELETE' then 253 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 254 | else 255 | -- Check if RLS allows the role to see the record 256 | perform 257 | set_config('role', working_role::text, true), 258 | set_config('request.jwt.claims', claims::text, true); 259 | 260 | execute 'execute walrus_rls_stmt' into subscription_has_access; 261 | 262 | if subscription_has_access then 263 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 264 | end if; 265 | end if; 266 | end loop; 267 | 268 | perform set_config('role', null, true); 269 | 270 | return next ( 271 | output, 272 | is_rls_enabled, 273 | visible_to_subscription_ids, 274 | case 275 | when error_record_exceeds_max_size then array['Error 413: Payload Too Large'] 276 | else '{}' 277 | end 278 | )::realtime.wal_rls; 279 | 280 | end if; 281 | end loop; 282 | 283 | perform set_config('role', null, true); 284 | end; 285 | $$; 286 | -------------------------------------------------------------------------------- /sql/walrus_migration_0004_in_op.sql: -------------------------------------------------------------------------------- 1 | alter type realtime.equality_op add value 'in'; 2 | 3 | create or replace function realtime.check_equality_op( 4 | op realtime.equality_op, 5 | type_ regtype, 6 | val_1 text, 7 | val_2 text 8 | ) 9 | returns bool 10 | immutable 11 | language plpgsql 12 | as $$ 13 | /* 14 | Casts *val_1* and *val_2* as type *type_* and check the *op* condition for truthiness 15 | */ 16 | declare 17 | op_symbol text = ( 18 | case 19 | when op = 'eq' then '=' 20 | when op = 'neq' then '!=' 21 | when op = 'lt' then '<' 22 | when op = 'lte' then '<=' 23 | when op = 'gt' then '>' 24 | when op = 'gte' then '>=' 25 | when op = 'in' then '= any' 26 | else 'UNKNOWN OP' 27 | end 28 | ); 29 | res boolean; 30 | begin 31 | execute format( 32 | 'select %L::'|| type_::text || ' ' || op_symbol 33 | || ' ( %L::' 34 | || ( 35 | case 36 | when op = 'in' then type_::text || '[]' 37 | else type_::text end 38 | ) 39 | || ')', val_1, val_2) into res; 40 | return res; 41 | end; 42 | $$; 43 | 44 | 45 | create or replace function realtime.subscription_check_filters() 46 | returns trigger 47 | language plpgsql 48 | as $$ 49 | /* 50 | Validates that the user defined filters for a subscription: 51 | - refer to valid columns that the claimed role may access 52 | - values are coercable to the correct column type 53 | */ 54 | declare 55 | col_names text[] = coalesce( 56 | array_agg(c.column_name order by c.ordinal_position), 57 | '{}'::text[] 58 | ) 59 | from 60 | information_schema.columns c 61 | where 62 | format('%I.%I', c.table_schema, c.table_name)::regclass = new.entity 63 | and pg_catalog.has_column_privilege( 64 | (new.claims ->> 'role'), 65 | format('%I.%I', c.table_schema, c.table_name)::regclass, 66 | c.column_name, 67 | 'SELECT' 68 | ); 69 | filter realtime.user_defined_filter; 70 | col_type regtype; 71 | 72 | in_val jsonb; 73 | begin 74 | for filter in select * from unnest(new.filters) loop 75 | -- Filtered column is valid 76 | if not filter.column_name = any(col_names) then 77 | raise exception 'invalid column for filter %', filter.column_name; 78 | end if; 79 | 80 | -- Type is sanitized and safe for string interpolation 81 | col_type = ( 82 | select atttypid::regtype 83 | from pg_catalog.pg_attribute 84 | where attrelid = new.entity 85 | and attname = filter.column_name 86 | ); 87 | if col_type is null then 88 | raise exception 'failed to lookup type for column %', filter.column_name; 89 | end if; 90 | 91 | -- Set maximum number of entries for in filter 92 | if filter.op = 'in'::realtime.equality_op then 93 | in_val = realtime.cast(filter.value, (col_type::text || '[]')::regtype); 94 | if coalesce(jsonb_array_length(in_val), 0) > 100 then 95 | raise exception 'too many values for `in` filter. Maximum 100'; 96 | end if; 97 | end if; 98 | 99 | -- raises an exception if value is not coercable to type 100 | perform realtime.cast(filter.value, col_type); 101 | end loop; 102 | 103 | -- Apply consistent order to filters so the unique constraint on 104 | -- (subscription_id, entity, filters) can't be tricked by a different filter order 105 | new.filters = coalesce( 106 | array_agg(f order by f.column_name, f.op, f.value), 107 | '{}' 108 | ) from unnest(new.filters) f; 109 | 110 | return new; 111 | end; 112 | $$; 113 | -------------------------------------------------------------------------------- /sql/walrus_migration_0005_delete_old_record_rls.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.apply_rls(wal jsonb, max_record_bytes int = 1024 * 1024) 2 | returns setof realtime.wal_rls 3 | language plpgsql 4 | volatile 5 | as $$ 6 | declare 7 | -- Regclass of the table e.g. public.notes 8 | entity_ regclass = (quote_ident(wal ->> 'schema') || '.' || quote_ident(wal ->> 'table'))::regclass; 9 | 10 | -- I, U, D, T: insert, update ... 11 | action realtime.action = ( 12 | case wal ->> 'action' 13 | when 'I' then 'INSERT' 14 | when 'U' then 'UPDATE' 15 | when 'D' then 'DELETE' 16 | else 'ERROR' 17 | end 18 | ); 19 | 20 | -- Is row level security enabled for the table 21 | is_rls_enabled bool = relrowsecurity from pg_class where oid = entity_; 22 | 23 | subscriptions realtime.subscription[] = array_agg(subs) 24 | from 25 | realtime.subscription subs 26 | where 27 | subs.entity = entity_; 28 | 29 | -- Subscription vars 30 | roles regrole[] = array_agg(distinct us.claims_role) 31 | from 32 | unnest(subscriptions) us; 33 | 34 | working_role regrole; 35 | claimed_role regrole; 36 | claims jsonb; 37 | 38 | subscription_id uuid; 39 | subscription_has_access bool; 40 | visible_to_subscription_ids uuid[] = '{}'; 41 | 42 | -- structured info for wal's columns 43 | columns realtime.wal_column[]; 44 | -- previous identity values for update/delete 45 | old_columns realtime.wal_column[]; 46 | 47 | error_record_exceeds_max_size boolean = octet_length(wal::text) > max_record_bytes; 48 | 49 | -- Primary jsonb output for record 50 | output jsonb; 51 | 52 | begin 53 | perform set_config('role', null, true); 54 | 55 | columns = 56 | array_agg( 57 | ( 58 | x->>'name', 59 | x->>'type', 60 | x->>'typeoid', 61 | realtime.cast( 62 | (x->'value') #>> '{}', 63 | coalesce( 64 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 65 | (x->>'type')::regtype 66 | ) 67 | ), 68 | (pks ->> 'name') is not null, 69 | true 70 | )::realtime.wal_column 71 | ) 72 | from 73 | jsonb_array_elements(wal -> 'columns') x 74 | left join jsonb_array_elements(wal -> 'pk') pks 75 | on (x ->> 'name') = (pks ->> 'name'); 76 | 77 | old_columns = 78 | array_agg( 79 | ( 80 | x->>'name', 81 | x->>'type', 82 | x->>'typeoid', 83 | realtime.cast( 84 | (x->'value') #>> '{}', 85 | coalesce( 86 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 87 | (x->>'type')::regtype 88 | ) 89 | ), 90 | (pks ->> 'name') is not null, 91 | true 92 | )::realtime.wal_column 93 | ) 94 | from 95 | jsonb_array_elements(wal -> 'identity') x 96 | left join jsonb_array_elements(wal -> 'pk') pks 97 | on (x ->> 'name') = (pks ->> 'name'); 98 | 99 | for working_role in select * from unnest(roles) loop 100 | 101 | -- Update `is_selectable` for columns and old_columns 102 | columns = 103 | array_agg( 104 | ( 105 | c.name, 106 | c.type_name, 107 | c.type_oid, 108 | c.value, 109 | c.is_pkey, 110 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 111 | )::realtime.wal_column 112 | ) 113 | from 114 | unnest(columns) c; 115 | 116 | old_columns = 117 | array_agg( 118 | ( 119 | c.name, 120 | c.type_name, 121 | c.type_oid, 122 | c.value, 123 | c.is_pkey, 124 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 125 | )::realtime.wal_column 126 | ) 127 | from 128 | unnest(old_columns) c; 129 | 130 | if action <> 'DELETE' and count(1) = 0 from unnest(columns) c where c.is_pkey then 131 | return next ( 132 | jsonb_build_object( 133 | 'schema', wal ->> 'schema', 134 | 'table', wal ->> 'table', 135 | 'type', action 136 | ), 137 | is_rls_enabled, 138 | -- subscriptions is already filtered by entity 139 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 140 | array['Error 400: Bad Request, no primary key'] 141 | )::realtime.wal_rls; 142 | 143 | -- The claims role does not have SELECT permission to the primary key of entity 144 | elsif action <> 'DELETE' and sum(c.is_selectable::int) <> count(1) from unnest(columns) c where c.is_pkey then 145 | return next ( 146 | jsonb_build_object( 147 | 'schema', wal ->> 'schema', 148 | 'table', wal ->> 'table', 149 | 'type', action 150 | ), 151 | is_rls_enabled, 152 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 153 | array['Error 401: Unauthorized'] 154 | )::realtime.wal_rls; 155 | 156 | else 157 | output = jsonb_build_object( 158 | 'schema', wal ->> 'schema', 159 | 'table', wal ->> 'table', 160 | 'type', action, 161 | 'commit_timestamp', to_char( 162 | (wal ->> 'timestamp')::timestamptz, 163 | 'YYYY-MM-DD"T"HH24:MI:SS"Z"' 164 | ), 165 | 'columns', ( 166 | select 167 | jsonb_agg( 168 | jsonb_build_object( 169 | 'name', pa.attname, 170 | 'type', pt.typname 171 | ) 172 | order by pa.attnum asc 173 | ) 174 | from 175 | pg_attribute pa 176 | join pg_type pt 177 | on pa.atttypid = pt.oid 178 | where 179 | attrelid = entity_ 180 | and attnum > 0 181 | and pg_catalog.has_column_privilege(working_role, entity_, pa.attname, 'SELECT') 182 | ) 183 | ) 184 | -- Add "record" key for insert and update 185 | || case 186 | when action in ('INSERT', 'UPDATE') then 187 | jsonb_build_object( 188 | 'record', 189 | ( 190 | select jsonb_object_agg((c).name, (c).value) 191 | from unnest(columns) c 192 | where 193 | (c).is_selectable 194 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 195 | ) 196 | ) 197 | else '{}'::jsonb 198 | end 199 | -- Add "old_record" key for update and delete 200 | || case 201 | when action = 'UPDATE' then 202 | jsonb_build_object( 203 | 'old_record', 204 | ( 205 | select jsonb_object_agg((c).name, (c).value) 206 | from unnest(old_columns) c 207 | where 208 | (c).is_selectable 209 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 210 | ) 211 | ) 212 | when action = 'DELETE' then 213 | jsonb_build_object( 214 | 'old_record', 215 | ( 216 | select jsonb_object_agg((c).name, (c).value) 217 | from unnest(old_columns) c 218 | where 219 | (c).is_selectable 220 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 221 | and ( not is_rls_enabled or (c).is_pkey ) -- if RLS enabled, we can't secure deletes so filter to pkey 222 | ) 223 | ) 224 | else '{}'::jsonb 225 | end; 226 | 227 | -- Create the prepared statement 228 | if is_rls_enabled and action <> 'DELETE' then 229 | if (select 1 from pg_prepared_statements where name = 'walrus_rls_stmt' limit 1) > 0 then 230 | deallocate walrus_rls_stmt; 231 | end if; 232 | execute realtime.build_prepared_statement_sql('walrus_rls_stmt', entity_, columns); 233 | end if; 234 | 235 | visible_to_subscription_ids = '{}'; 236 | 237 | for subscription_id, claims in ( 238 | select 239 | subs.subscription_id, 240 | subs.claims 241 | from 242 | unnest(subscriptions) subs 243 | where 244 | subs.entity = entity_ 245 | and subs.claims_role = working_role 246 | and ( 247 | realtime.is_visible_through_filters(columns, subs.filters) 248 | or action = 'DELETE' 249 | ) 250 | ) loop 251 | 252 | if not is_rls_enabled or action = 'DELETE' then 253 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 254 | else 255 | -- Check if RLS allows the role to see the record 256 | perform 257 | set_config('role', working_role::text, true), 258 | set_config('request.jwt.claims', claims::text, true); 259 | 260 | execute 'execute walrus_rls_stmt' into subscription_has_access; 261 | 262 | if subscription_has_access then 263 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 264 | end if; 265 | end if; 266 | end loop; 267 | 268 | perform set_config('role', null, true); 269 | 270 | return next ( 271 | output, 272 | is_rls_enabled, 273 | visible_to_subscription_ids, 274 | case 275 | when error_record_exceeds_max_size then array['Error 413: Payload Too Large'] 276 | else '{}' 277 | end 278 | )::realtime.wal_rls; 279 | 280 | end if; 281 | end loop; 282 | 283 | perform set_config('role', null, true); 284 | end; 285 | $$; 286 | -------------------------------------------------------------------------------- /sql/walrus_migration_0006_high_res_commit_timestamp.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.apply_rls(wal jsonb, max_record_bytes int = 1024 * 1024) 2 | returns setof realtime.wal_rls 3 | language plpgsql 4 | volatile 5 | as $$ 6 | declare 7 | -- Regclass of the table e.g. public.notes 8 | entity_ regclass = (quote_ident(wal ->> 'schema') || '.' || quote_ident(wal ->> 'table'))::regclass; 9 | 10 | -- I, U, D, T: insert, update ... 11 | action realtime.action = ( 12 | case wal ->> 'action' 13 | when 'I' then 'INSERT' 14 | when 'U' then 'UPDATE' 15 | when 'D' then 'DELETE' 16 | else 'ERROR' 17 | end 18 | ); 19 | 20 | -- Is row level security enabled for the table 21 | is_rls_enabled bool = relrowsecurity from pg_class where oid = entity_; 22 | 23 | subscriptions realtime.subscription[] = array_agg(subs) 24 | from 25 | realtime.subscription subs 26 | where 27 | subs.entity = entity_; 28 | 29 | -- Subscription vars 30 | roles regrole[] = array_agg(distinct us.claims_role) 31 | from 32 | unnest(subscriptions) us; 33 | 34 | working_role regrole; 35 | claimed_role regrole; 36 | claims jsonb; 37 | 38 | subscription_id uuid; 39 | subscription_has_access bool; 40 | visible_to_subscription_ids uuid[] = '{}'; 41 | 42 | -- structured info for wal's columns 43 | columns realtime.wal_column[]; 44 | -- previous identity values for update/delete 45 | old_columns realtime.wal_column[]; 46 | 47 | error_record_exceeds_max_size boolean = octet_length(wal::text) > max_record_bytes; 48 | 49 | -- Primary jsonb output for record 50 | output jsonb; 51 | 52 | begin 53 | perform set_config('role', null, true); 54 | 55 | columns = 56 | array_agg( 57 | ( 58 | x->>'name', 59 | x->>'type', 60 | x->>'typeoid', 61 | realtime.cast( 62 | (x->'value') #>> '{}', 63 | coalesce( 64 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 65 | (x->>'type')::regtype 66 | ) 67 | ), 68 | (pks ->> 'name') is not null, 69 | true 70 | )::realtime.wal_column 71 | ) 72 | from 73 | jsonb_array_elements(wal -> 'columns') x 74 | left join jsonb_array_elements(wal -> 'pk') pks 75 | on (x ->> 'name') = (pks ->> 'name'); 76 | 77 | old_columns = 78 | array_agg( 79 | ( 80 | x->>'name', 81 | x->>'type', 82 | x->>'typeoid', 83 | realtime.cast( 84 | (x->'value') #>> '{}', 85 | coalesce( 86 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 87 | (x->>'type')::regtype 88 | ) 89 | ), 90 | (pks ->> 'name') is not null, 91 | true 92 | )::realtime.wal_column 93 | ) 94 | from 95 | jsonb_array_elements(wal -> 'identity') x 96 | left join jsonb_array_elements(wal -> 'pk') pks 97 | on (x ->> 'name') = (pks ->> 'name'); 98 | 99 | for working_role in select * from unnest(roles) loop 100 | 101 | -- Update `is_selectable` for columns and old_columns 102 | columns = 103 | array_agg( 104 | ( 105 | c.name, 106 | c.type_name, 107 | c.type_oid, 108 | c.value, 109 | c.is_pkey, 110 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 111 | )::realtime.wal_column 112 | ) 113 | from 114 | unnest(columns) c; 115 | 116 | old_columns = 117 | array_agg( 118 | ( 119 | c.name, 120 | c.type_name, 121 | c.type_oid, 122 | c.value, 123 | c.is_pkey, 124 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 125 | )::realtime.wal_column 126 | ) 127 | from 128 | unnest(old_columns) c; 129 | 130 | if action <> 'DELETE' and count(1) = 0 from unnest(columns) c where c.is_pkey then 131 | return next ( 132 | jsonb_build_object( 133 | 'schema', wal ->> 'schema', 134 | 'table', wal ->> 'table', 135 | 'type', action 136 | ), 137 | is_rls_enabled, 138 | -- subscriptions is already filtered by entity 139 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 140 | array['Error 400: Bad Request, no primary key'] 141 | )::realtime.wal_rls; 142 | 143 | -- The claims role does not have SELECT permission to the primary key of entity 144 | elsif action <> 'DELETE' and sum(c.is_selectable::int) <> count(1) from unnest(columns) c where c.is_pkey then 145 | return next ( 146 | jsonb_build_object( 147 | 'schema', wal ->> 'schema', 148 | 'table', wal ->> 'table', 149 | 'type', action 150 | ), 151 | is_rls_enabled, 152 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 153 | array['Error 401: Unauthorized'] 154 | )::realtime.wal_rls; 155 | 156 | else 157 | output = jsonb_build_object( 158 | 'schema', wal ->> 'schema', 159 | 'table', wal ->> 'table', 160 | 'type', action, 161 | 'commit_timestamp', to_char( 162 | (wal ->> 'timestamp')::timestamptz, 163 | 'YYYY-MM-DD"T"HH24:MI:SS.MS"Z"' 164 | ), 165 | 'columns', ( 166 | select 167 | jsonb_agg( 168 | jsonb_build_object( 169 | 'name', pa.attname, 170 | 'type', pt.typname 171 | ) 172 | order by pa.attnum asc 173 | ) 174 | from 175 | pg_attribute pa 176 | join pg_type pt 177 | on pa.atttypid = pt.oid 178 | where 179 | attrelid = entity_ 180 | and attnum > 0 181 | and pg_catalog.has_column_privilege(working_role, entity_, pa.attname, 'SELECT') 182 | ) 183 | ) 184 | -- Add "record" key for insert and update 185 | || case 186 | when action in ('INSERT', 'UPDATE') then 187 | jsonb_build_object( 188 | 'record', 189 | ( 190 | select jsonb_object_agg((c).name, (c).value) 191 | from unnest(columns) c 192 | where 193 | (c).is_selectable 194 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 195 | ) 196 | ) 197 | else '{}'::jsonb 198 | end 199 | -- Add "old_record" key for update and delete 200 | || case 201 | when action = 'UPDATE' then 202 | jsonb_build_object( 203 | 'old_record', 204 | ( 205 | select jsonb_object_agg((c).name, (c).value) 206 | from unnest(old_columns) c 207 | where 208 | (c).is_selectable 209 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 210 | ) 211 | ) 212 | when action = 'DELETE' then 213 | jsonb_build_object( 214 | 'old_record', 215 | ( 216 | select jsonb_object_agg((c).name, (c).value) 217 | from unnest(old_columns) c 218 | where 219 | (c).is_selectable 220 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 221 | and ( not is_rls_enabled or (c).is_pkey ) -- if RLS enabled, we can't secure deletes so filter to pkey 222 | ) 223 | ) 224 | else '{}'::jsonb 225 | end; 226 | 227 | -- Create the prepared statement 228 | if is_rls_enabled and action <> 'DELETE' then 229 | if (select 1 from pg_prepared_statements where name = 'walrus_rls_stmt' limit 1) > 0 then 230 | deallocate walrus_rls_stmt; 231 | end if; 232 | execute realtime.build_prepared_statement_sql('walrus_rls_stmt', entity_, columns); 233 | end if; 234 | 235 | visible_to_subscription_ids = '{}'; 236 | 237 | for subscription_id, claims in ( 238 | select 239 | subs.subscription_id, 240 | subs.claims 241 | from 242 | unnest(subscriptions) subs 243 | where 244 | subs.entity = entity_ 245 | and subs.claims_role = working_role 246 | and ( 247 | realtime.is_visible_through_filters(columns, subs.filters) 248 | or action = 'DELETE' 249 | ) 250 | ) loop 251 | 252 | if not is_rls_enabled or action = 'DELETE' then 253 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 254 | else 255 | -- Check if RLS allows the role to see the record 256 | perform 257 | set_config('role', working_role::text, true), 258 | set_config('request.jwt.claims', claims::text, true); 259 | 260 | execute 'execute walrus_rls_stmt' into subscription_has_access; 261 | 262 | if subscription_has_access then 263 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 264 | end if; 265 | end if; 266 | end loop; 267 | 268 | perform set_config('role', null, true); 269 | 270 | return next ( 271 | output, 272 | is_rls_enabled, 273 | visible_to_subscription_ids, 274 | case 275 | when error_record_exceeds_max_size then array['Error 413: Payload Too Large'] 276 | else '{}' 277 | end 278 | )::realtime.wal_rls; 279 | 280 | end if; 281 | end loop; 282 | 283 | perform set_config('role', null, true); 284 | end; 285 | $$; 286 | -------------------------------------------------------------------------------- /sql/walrus_migration_0007_commit_timestamp_utc.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.apply_rls(wal jsonb, max_record_bytes int = 1024 * 1024) 2 | returns setof realtime.wal_rls 3 | language plpgsql 4 | volatile 5 | as $$ 6 | declare 7 | -- Regclass of the table e.g. public.notes 8 | entity_ regclass = (quote_ident(wal ->> 'schema') || '.' || quote_ident(wal ->> 'table'))::regclass; 9 | 10 | -- I, U, D, T: insert, update ... 11 | action realtime.action = ( 12 | case wal ->> 'action' 13 | when 'I' then 'INSERT' 14 | when 'U' then 'UPDATE' 15 | when 'D' then 'DELETE' 16 | else 'ERROR' 17 | end 18 | ); 19 | 20 | -- Is row level security enabled for the table 21 | is_rls_enabled bool = relrowsecurity from pg_class where oid = entity_; 22 | 23 | subscriptions realtime.subscription[] = array_agg(subs) 24 | from 25 | realtime.subscription subs 26 | where 27 | subs.entity = entity_; 28 | 29 | -- Subscription vars 30 | roles regrole[] = array_agg(distinct us.claims_role) 31 | from 32 | unnest(subscriptions) us; 33 | 34 | working_role regrole; 35 | claimed_role regrole; 36 | claims jsonb; 37 | 38 | subscription_id uuid; 39 | subscription_has_access bool; 40 | visible_to_subscription_ids uuid[] = '{}'; 41 | 42 | -- structured info for wal's columns 43 | columns realtime.wal_column[]; 44 | -- previous identity values for update/delete 45 | old_columns realtime.wal_column[]; 46 | 47 | error_record_exceeds_max_size boolean = octet_length(wal::text) > max_record_bytes; 48 | 49 | -- Primary jsonb output for record 50 | output jsonb; 51 | 52 | begin 53 | perform set_config('role', null, true); 54 | 55 | columns = 56 | array_agg( 57 | ( 58 | x->>'name', 59 | x->>'type', 60 | x->>'typeoid', 61 | realtime.cast( 62 | (x->'value') #>> '{}', 63 | coalesce( 64 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 65 | (x->>'type')::regtype 66 | ) 67 | ), 68 | (pks ->> 'name') is not null, 69 | true 70 | )::realtime.wal_column 71 | ) 72 | from 73 | jsonb_array_elements(wal -> 'columns') x 74 | left join jsonb_array_elements(wal -> 'pk') pks 75 | on (x ->> 'name') = (pks ->> 'name'); 76 | 77 | old_columns = 78 | array_agg( 79 | ( 80 | x->>'name', 81 | x->>'type', 82 | x->>'typeoid', 83 | realtime.cast( 84 | (x->'value') #>> '{}', 85 | coalesce( 86 | (x->>'typeoid')::regtype, -- null when wal2json version <= 2.4 87 | (x->>'type')::regtype 88 | ) 89 | ), 90 | (pks ->> 'name') is not null, 91 | true 92 | )::realtime.wal_column 93 | ) 94 | from 95 | jsonb_array_elements(wal -> 'identity') x 96 | left join jsonb_array_elements(wal -> 'pk') pks 97 | on (x ->> 'name') = (pks ->> 'name'); 98 | 99 | for working_role in select * from unnest(roles) loop 100 | 101 | -- Update `is_selectable` for columns and old_columns 102 | columns = 103 | array_agg( 104 | ( 105 | c.name, 106 | c.type_name, 107 | c.type_oid, 108 | c.value, 109 | c.is_pkey, 110 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 111 | )::realtime.wal_column 112 | ) 113 | from 114 | unnest(columns) c; 115 | 116 | old_columns = 117 | array_agg( 118 | ( 119 | c.name, 120 | c.type_name, 121 | c.type_oid, 122 | c.value, 123 | c.is_pkey, 124 | pg_catalog.has_column_privilege(working_role, entity_, c.name, 'SELECT') 125 | )::realtime.wal_column 126 | ) 127 | from 128 | unnest(old_columns) c; 129 | 130 | if action <> 'DELETE' and count(1) = 0 from unnest(columns) c where c.is_pkey then 131 | return next ( 132 | jsonb_build_object( 133 | 'schema', wal ->> 'schema', 134 | 'table', wal ->> 'table', 135 | 'type', action 136 | ), 137 | is_rls_enabled, 138 | -- subscriptions is already filtered by entity 139 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 140 | array['Error 400: Bad Request, no primary key'] 141 | )::realtime.wal_rls; 142 | 143 | -- The claims role does not have SELECT permission to the primary key of entity 144 | elsif action <> 'DELETE' and sum(c.is_selectable::int) <> count(1) from unnest(columns) c where c.is_pkey then 145 | return next ( 146 | jsonb_build_object( 147 | 'schema', wal ->> 'schema', 148 | 'table', wal ->> 'table', 149 | 'type', action 150 | ), 151 | is_rls_enabled, 152 | (select array_agg(s.subscription_id) from unnest(subscriptions) as s where claims_role = working_role), 153 | array['Error 401: Unauthorized'] 154 | )::realtime.wal_rls; 155 | 156 | else 157 | output = jsonb_build_object( 158 | 'schema', wal ->> 'schema', 159 | 'table', wal ->> 'table', 160 | 'type', action, 161 | 'commit_timestamp', to_char( 162 | ((wal ->> 'timestamp')::timestamptz at time zone 'utc'), 163 | 'YYYY-MM-DD"T"HH24:MI:SS.MS"Z"' 164 | ), 165 | 'columns', ( 166 | select 167 | jsonb_agg( 168 | jsonb_build_object( 169 | 'name', pa.attname, 170 | 'type', pt.typname 171 | ) 172 | order by pa.attnum asc 173 | ) 174 | from 175 | pg_attribute pa 176 | join pg_type pt 177 | on pa.atttypid = pt.oid 178 | where 179 | attrelid = entity_ 180 | and attnum > 0 181 | and pg_catalog.has_column_privilege(working_role, entity_, pa.attname, 'SELECT') 182 | ) 183 | ) 184 | -- Add "record" key for insert and update 185 | || case 186 | when action in ('INSERT', 'UPDATE') then 187 | jsonb_build_object( 188 | 'record', 189 | ( 190 | select jsonb_object_agg((c).name, (c).value) 191 | from unnest(columns) c 192 | where 193 | (c).is_selectable 194 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 195 | ) 196 | ) 197 | else '{}'::jsonb 198 | end 199 | -- Add "old_record" key for update and delete 200 | || case 201 | when action = 'UPDATE' then 202 | jsonb_build_object( 203 | 'old_record', 204 | ( 205 | select jsonb_object_agg((c).name, (c).value) 206 | from unnest(old_columns) c 207 | where 208 | (c).is_selectable 209 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 210 | ) 211 | ) 212 | when action = 'DELETE' then 213 | jsonb_build_object( 214 | 'old_record', 215 | ( 216 | select jsonb_object_agg((c).name, (c).value) 217 | from unnest(old_columns) c 218 | where 219 | (c).is_selectable 220 | and ( not error_record_exceeds_max_size or (octet_length((c).value::text) <= 64)) 221 | and ( not is_rls_enabled or (c).is_pkey ) -- if RLS enabled, we can't secure deletes so filter to pkey 222 | ) 223 | ) 224 | else '{}'::jsonb 225 | end; 226 | 227 | -- Create the prepared statement 228 | if is_rls_enabled and action <> 'DELETE' then 229 | if (select 1 from pg_prepared_statements where name = 'walrus_rls_stmt' limit 1) > 0 then 230 | deallocate walrus_rls_stmt; 231 | end if; 232 | execute realtime.build_prepared_statement_sql('walrus_rls_stmt', entity_, columns); 233 | end if; 234 | 235 | visible_to_subscription_ids = '{}'; 236 | 237 | for subscription_id, claims in ( 238 | select 239 | subs.subscription_id, 240 | subs.claims 241 | from 242 | unnest(subscriptions) subs 243 | where 244 | subs.entity = entity_ 245 | and subs.claims_role = working_role 246 | and ( 247 | realtime.is_visible_through_filters(columns, subs.filters) 248 | or action = 'DELETE' 249 | ) 250 | ) loop 251 | 252 | if not is_rls_enabled or action = 'DELETE' then 253 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 254 | else 255 | -- Check if RLS allows the role to see the record 256 | perform 257 | set_config('role', working_role::text, true), 258 | set_config('request.jwt.claims', claims::text, true); 259 | 260 | execute 'execute walrus_rls_stmt' into subscription_has_access; 261 | 262 | if subscription_has_access then 263 | visible_to_subscription_ids = visible_to_subscription_ids || subscription_id; 264 | end if; 265 | end if; 266 | end loop; 267 | 268 | perform set_config('role', null, true); 269 | 270 | return next ( 271 | output, 272 | is_rls_enabled, 273 | visible_to_subscription_ids, 274 | case 275 | when error_record_exceeds_max_size then array['Error 413: Payload Too Large'] 276 | else '{}' 277 | end 278 | )::realtime.wal_rls; 279 | 280 | end if; 281 | end loop; 282 | 283 | perform set_config('role', null, true); 284 | end; 285 | $$; 286 | -------------------------------------------------------------------------------- /sql/walrus_migration_0008_subscription_check_array_types.sql: -------------------------------------------------------------------------------- 1 | create or replace function realtime.subscription_check_filters() 2 | returns trigger 3 | language plpgsql 4 | as $$ 5 | /* 6 | Validates that the user defined filters for a subscription: 7 | - refer to valid columns that the claimed role may access 8 | - values are coercable to the correct column type 9 | */ 10 | declare 11 | col_names text[] = coalesce( 12 | array_agg(c.column_name order by c.ordinal_position), 13 | '{}'::text[] 14 | ) 15 | from 16 | information_schema.columns c 17 | where 18 | format('%I.%I', c.table_schema, c.table_name)::regclass = new.entity 19 | and pg_catalog.has_column_privilege( 20 | (new.claims ->> 'role'), 21 | format('%I.%I', c.table_schema, c.table_name)::regclass, 22 | c.column_name, 23 | 'SELECT' 24 | ); 25 | filter realtime.user_defined_filter; 26 | col_type regtype; 27 | 28 | in_val jsonb; 29 | begin 30 | for filter in select * from unnest(new.filters) loop 31 | -- Filtered column is valid 32 | if not filter.column_name = any(col_names) then 33 | raise exception 'invalid column for filter %', filter.column_name; 34 | end if; 35 | 36 | -- Type is sanitized and safe for string interpolation 37 | col_type = ( 38 | select atttypid::regtype 39 | from pg_catalog.pg_attribute 40 | where attrelid = new.entity 41 | and attname = filter.column_name 42 | ); 43 | if col_type is null then 44 | raise exception 'failed to lookup type for column %', filter.column_name; 45 | end if; 46 | 47 | -- Set maximum number of entries for in filter 48 | if filter.op = 'in'::realtime.equality_op then 49 | in_val = realtime.cast(filter.value, (col_type::text || '[]')::regtype); 50 | if coalesce(jsonb_array_length(in_val), 0) > 100 then 51 | raise exception 'too many values for `in` filter. Maximum 100'; 52 | end if; 53 | else 54 | -- raises an exception if value is not coercable to type 55 | perform realtime.cast(filter.value, col_type); 56 | end if; 57 | 58 | end loop; 59 | 60 | -- Apply consistent order to filters so the unique constraint on 61 | -- (subscription_id, entity, filters) can't be tricked by a different filter order 62 | new.filters = coalesce( 63 | array_agg(f order by f.column_name, f.op, f.value), 64 | '{}' 65 | ) from unnest(new.filters) f; 66 | 67 | return new; 68 | end; 69 | $$; 70 | -------------------------------------------------------------------------------- /test/expected/issue_40_quoted_regtype.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that, regtypes that require quoting are handled without exception 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ?column? 6 | ---------- 7 | 1 8 | (1 row) 9 | 10 | create type "Color" as enum ('RED', 'YELLOW', 'GREEN'); 11 | create table public.notes( 12 | id int primary key, 13 | primary_color "Color" 14 | ); 15 | create policy rls_color_is_red 16 | on public.notes 17 | to authenticated 18 | using (primary_color = 'RED'); 19 | alter table public.notes enable row level security; 20 | insert into realtime.subscription(subscription_id, entity, claims, filters) 21 | select 22 | seed_uuid(1), 23 | 'public.notes', 24 | jsonb_build_object( 25 | 'role', 'authenticated', 26 | 'sub', seed_uuid(2)::text 27 | ), 28 | array[('primary_color', 'eq', 'RED')::realtime.user_defined_filter]; 29 | insert into public.notes(id, primary_color) 30 | values 31 | (1, 'RED'), -- matches filter 32 | (2, 'GREEN'); -- does not match filter 33 | select 34 | rec, 35 | is_rls_enabled, 36 | subscription_ids, 37 | errors 38 | from 39 | walrus; 40 | rec | is_rls_enabled | subscription_ids | errors 41 | ----------------------------------------------------+----------------+----------------------------------------+-------- 42 | { +| t | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 43 | "type": "INSERT", +| | | 44 | "table": "notes", +| | | 45 | "record": { +| | | 46 | "id": 1, +| | | 47 | "primary_color": "RED" +| | | 48 | }, +| | | 49 | "schema": "public", +| | | 50 | "columns": [ +| | | 51 | { +| | | 52 | "name": "id", +| | | 53 | "type": "int4" +| | | 54 | }, +| | | 55 | { +| | | 56 | "name": "primary_color", +| | | 57 | "type": "Color" +| | | 58 | } +| | | 59 | ], +| | | 60 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 61 | } | | | 62 | { +| t | {} | {} 63 | "type": "INSERT", +| | | 64 | "table": "notes", +| | | 65 | "record": { +| | | 66 | "id": 2, +| | | 67 | "primary_color": "GREEN" +| | | 68 | }, +| | | 69 | "schema": "public", +| | | 70 | "columns": [ +| | | 71 | { +| | | 72 | "name": "id", +| | | 73 | "type": "int4" +| | | 74 | }, +| | | 75 | { +| | | 76 | "name": "primary_color", +| | | 77 | "type": "Color" +| | | 78 | } +| | | 79 | ], +| | | 80 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 81 | } | | | 82 | (2 rows) 83 | 84 | drop table public.notes; 85 | select pg_drop_replication_slot('realtime'); 86 | pg_drop_replication_slot 87 | -------------------------- 88 | 89 | (1 row) 90 | 91 | truncate table realtime.subscription; 92 | -------------------------------------------------------------------------------- /test/expected/issue_50_delete_filters.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | insert into realtime.subscription(subscription_id, entity, claims, filters) 12 | select 13 | seed_uuid(id), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(id)::text 19 | ), 20 | array[(column_name, op, value)::realtime.user_defined_filter] 21 | from 22 | ( 23 | values 24 | (1 , 'body', 'eq', 'bbb'), 25 | (2 , 'id', 'eq', '2') 26 | ) f(id, column_name, op, value); 27 | select subscription_id, filters from realtime.subscription; 28 | subscription_id | filters 29 | --------------------------------------+------------------- 30 | f4539ebe-c779-5788-bbc1-2421ffaa8954 | {"(body,eq,bbb)"} 31 | 5211e8ec-8c25-5c7f-9b03-6ff1eac0159e | {"(id,eq,2)"} 32 | (2 rows) 33 | 34 | ---------------------------------------------------------------------------------------- 35 | -- When Replica Identity is Not Full, only filters referencing the pkey are respected -- 36 | ---------------------------------------------------------------------------------------- 37 | insert into public.notes(id, body) 38 | values 39 | (1, 'bbb'), 40 | (2, 'ccc'); 41 | select clear_wal(); 42 | clear_wal 43 | ----------- 44 | 45 | (1 row) 46 | 47 | delete from public.notes; 48 | select 49 | rec, 50 | is_rls_enabled, 51 | subscription_ids, 52 | errors 53 | from 54 | walrus; 55 | rec | is_rls_enabled | subscription_ids | errors 56 | ----------------------------------------------------+----------------+----------------------------------------+-------- 57 | { +| f | {} | {} 58 | "type": "DELETE", +| | | 59 | "table": "notes", +| | | 60 | "schema": "public", +| | | 61 | "columns": [ +| | | 62 | { +| | | 63 | "name": "id", +| | | 64 | "type": "int4" +| | | 65 | }, +| | | 66 | { +| | | 67 | "name": "body", +| | | 68 | "type": "text" +| | | 69 | } +| | | 70 | ], +| | | 71 | "old_record": { +| | | 72 | "id": 1 +| | | 73 | }, +| | | 74 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 75 | } | | | 76 | { +| f | {5211e8ec-8c25-5c7f-9b03-6ff1eac0159e} | {} 77 | "type": "DELETE", +| | | 78 | "table": "notes", +| | | 79 | "schema": "public", +| | | 80 | "columns": [ +| | | 81 | { +| | | 82 | "name": "id", +| | | 83 | "type": "int4" +| | | 84 | }, +| | | 85 | { +| | | 86 | "name": "body", +| | | 87 | "type": "text" +| | | 88 | } +| | | 89 | ], +| | | 90 | "old_record": { +| | | 91 | "id": 2 +| | | 92 | }, +| | | 93 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 94 | } | | | 95 | (2 rows) 96 | 97 | ---------------------------------------------------------------------------------------- 98 | -- When Replica Identity is Not Full, only filters referencing the pkey are respected -- 99 | ---------------------------------------------------------------------------------------- 100 | alter table public.notes replica identity full; 101 | insert into public.notes(id, body) 102 | values 103 | (1, 'bbb'), 104 | (2, 'ccc'); 105 | select clear_wal(); 106 | clear_wal 107 | ----------- 108 | 109 | (1 row) 110 | 111 | delete from public.notes; 112 | select 113 | rec, 114 | is_rls_enabled, 115 | subscription_ids, 116 | errors 117 | from 118 | walrus; 119 | rec | is_rls_enabled | subscription_ids | errors 120 | ----------------------------------------------------+----------------+----------------------------------------+-------- 121 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 122 | "type": "DELETE", +| | | 123 | "table": "notes", +| | | 124 | "schema": "public", +| | | 125 | "columns": [ +| | | 126 | { +| | | 127 | "name": "id", +| | | 128 | "type": "int4" +| | | 129 | }, +| | | 130 | { +| | | 131 | "name": "body", +| | | 132 | "type": "text" +| | | 133 | } +| | | 134 | ], +| | | 135 | "old_record": { +| | | 136 | "id": 1, +| | | 137 | "body": "bbb" +| | | 138 | }, +| | | 139 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 140 | } | | | 141 | { +| f | {5211e8ec-8c25-5c7f-9b03-6ff1eac0159e} | {} 142 | "type": "DELETE", +| | | 143 | "table": "notes", +| | | 144 | "schema": "public", +| | | 145 | "columns": [ +| | | 146 | { +| | | 147 | "name": "id", +| | | 148 | "type": "int4" +| | | 149 | }, +| | | 150 | { +| | | 151 | "name": "body", +| | | 152 | "type": "text" +| | | 153 | } +| | | 154 | ], +| | | 155 | "old_record": { +| | | 156 | "id": 2, +| | | 157 | "body": "ccc" +| | | 158 | }, +| | | 159 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 160 | } | | | 161 | (2 rows) 162 | 163 | drop table public.notes; 164 | select pg_drop_replication_slot('realtime'); 165 | pg_drop_replication_slot 166 | -------------------------- 167 | 168 | (1 row) 169 | 170 | truncate table realtime.subscription; 171 | -------------------------------------------------------------------------------- /test/expected/issue_55_null_passes_filters.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id serial primary key, 9 | page_id int 10 | ); 11 | insert into realtime.subscription(subscription_id, entity, claims, filters) 12 | select 13 | seed_uuid(1), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(1)::text 19 | ), 20 | array[('page_id', 'eq', '5')::realtime.user_defined_filter]; 21 | select clear_wal(); 22 | clear_wal 23 | ----------- 24 | 25 | (1 row) 26 | 27 | -- Expect 0 subscriptions: filters do not match: 5 <> 1 28 | insert into public.notes(page_id) values (1); 29 | select 30 | rec, 31 | is_rls_enabled, 32 | subscription_ids, 33 | errors 34 | from 35 | walrus; 36 | rec | is_rls_enabled | subscription_ids | errors 37 | ----------------------------------------------------+----------------+------------------+-------- 38 | { +| f | {} | {} 39 | "type": "INSERT", +| | | 40 | "table": "notes", +| | | 41 | "record": { +| | | 42 | "id": 1, +| | | 43 | "page_id": 1 +| | | 44 | }, +| | | 45 | "schema": "public", +| | | 46 | "columns": [ +| | | 47 | { +| | | 48 | "name": "id", +| | | 49 | "type": "int4" +| | | 50 | }, +| | | 51 | { +| | | 52 | "name": "page_id", +| | | 53 | "type": "int4" +| | | 54 | } +| | | 55 | ], +| | | 56 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 57 | } | | | 58 | (1 row) 59 | 60 | -- Expect 1 subscription: filters do match 5 = 5 61 | insert into public.notes(page_id) values (5); 62 | select 63 | rec, 64 | is_rls_enabled, 65 | subscription_ids, 66 | errors 67 | from 68 | walrus; 69 | rec | is_rls_enabled | subscription_ids | errors 70 | ----------------------------------------------------+----------------+----------------------------------------+-------- 71 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 72 | "type": "INSERT", +| | | 73 | "table": "notes", +| | | 74 | "record": { +| | | 75 | "id": 2, +| | | 76 | "page_id": 5 +| | | 77 | }, +| | | 78 | "schema": "public", +| | | 79 | "columns": [ +| | | 80 | { +| | | 81 | "name": "id", +| | | 82 | "type": "int4" +| | | 83 | }, +| | | 84 | { +| | | 85 | "name": "page_id", +| | | 86 | "type": "int4" +| | | 87 | } +| | | 88 | ], +| | | 89 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 90 | } | | | 91 | (1 row) 92 | 93 | -- Expect 0 subscriptions: filters do match 5 <> null 94 | insert into public.notes(page_id) values (null); 95 | select 96 | rec, 97 | is_rls_enabled, 98 | subscription_ids, 99 | errors 100 | from 101 | walrus; 102 | rec | is_rls_enabled | subscription_ids | errors 103 | ----------------------------------------------------+----------------+------------------+-------- 104 | { +| f | {} | {} 105 | "type": "INSERT", +| | | 106 | "table": "notes", +| | | 107 | "record": { +| | | 108 | "id": 3, +| | | 109 | "page_id": null +| | | 110 | }, +| | | 111 | "schema": "public", +| | | 112 | "columns": [ +| | | 113 | { +| | | 114 | "name": "id", +| | | 115 | "type": "int4" +| | | 116 | }, +| | | 117 | { +| | | 118 | "name": "page_id", +| | | 119 | "type": "int4" +| | | 120 | } +| | | 121 | ], +| | | 122 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 123 | } | | | 124 | (1 row) 125 | 126 | drop table public.notes; 127 | select pg_drop_replication_slot('realtime'); 128 | pg_drop_replication_slot 129 | -------------------------- 130 | 131 | (1 row) 132 | 133 | truncate table realtime.subscription; 134 | -------------------------------------------------------------------------------- /test/expected/test_column_permissions_hide_columns.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that, when a role does not have select access to a column, it is omitted 3 | from realtime output 4 | 5 | In this case, we omit the "body" column 6 | */ 7 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 8 | ?column? 9 | ---------- 10 | 1 11 | (1 row) 12 | 13 | create table public.notes( 14 | id int primary key, 15 | body text 16 | ); 17 | revoke select on public.notes from authenticated; 18 | grant select (id) on public.notes to authenticated; 19 | insert into realtime.subscription(subscription_id, entity, claims) 20 | select 21 | seed_uuid(1), 22 | 'public.notes', 23 | jsonb_build_object( 24 | 'role', 'authenticated', 25 | 'sub', seed_uuid(2)::text 26 | ); 27 | insert into public.notes(id, body) values (1, 'hello'); 28 | select 29 | rec, 30 | is_rls_enabled, 31 | subscription_ids, 32 | errors 33 | from 34 | walrus; 35 | rec | is_rls_enabled | subscription_ids | errors 36 | ----------------------------------------------------+----------------+----------------------------------------+-------- 37 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 38 | "type": "INSERT", +| | | 39 | "table": "notes", +| | | 40 | "record": { +| | | 41 | "id": 1 +| | | 42 | }, +| | | 43 | "schema": "public", +| | | 44 | "columns": [ +| | | 45 | { +| | | 46 | "name": "id", +| | | 47 | "type": "int4" +| | | 48 | } +| | | 49 | ], +| | | 50 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 51 | } | | | 52 | (1 row) 53 | 54 | drop table public.notes; 55 | select pg_drop_replication_slot('realtime'); 56 | pg_drop_replication_slot 57 | -------------------------- 58 | 59 | (1 row) 60 | 61 | truncate table realtime.subscription; 62 | -------------------------------------------------------------------------------- /test/expected/test_error_no_primary_key.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ?column? 6 | ---------- 7 | 1 8 | (1 row) 9 | 10 | create table public.notes( 11 | id int 12 | ); 13 | insert into realtime.subscription(subscription_id, entity, claims) 14 | select 15 | seed_uuid(1), 16 | 'public.notes', 17 | jsonb_build_object( 18 | 'role', 'authenticated', 19 | 'email', 'example@example.com', 20 | 'sub', seed_uuid(2)::text 21 | ); 22 | select clear_wal(); 23 | clear_wal 24 | ----------- 25 | 26 | (1 row) 27 | 28 | insert into public.notes(id) values (1); 29 | select 30 | rec, 31 | is_rls_enabled, 32 | subscription_ids, 33 | errors 34 | from 35 | walrus; 36 | rec | is_rls_enabled | subscription_ids | errors 37 | ------------------------+----------------+----------------------------------------+-------------------------------------------- 38 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {"Error 400: Bad Request, no primary key"} 39 | "type": "INSERT", +| | | 40 | "table": "notes", +| | | 41 | "schema": "public"+| | | 42 | } | | | 43 | (1 row) 44 | 45 | drop table public.notes; 46 | select pg_drop_replication_slot('realtime'); 47 | pg_drop_replication_slot 48 | -------------------------- 49 | 50 | (1 row) 51 | 52 | truncate table realtime.subscription; 53 | -------------------------------------------------------------------------------- /test/expected/test_error_payload_too_large.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ?column? 6 | ---------- 7 | 1 8 | (1 row) 9 | 10 | create table public.notes( 11 | id int primary key, 12 | body text 13 | ); 14 | insert into realtime.subscription(subscription_id, entity, claims) 15 | select 16 | seed_uuid(1), 17 | 'public.notes', 18 | jsonb_build_object( 19 | 'role', 'authenticated', 20 | 'email', 'example@example.com', 21 | 'sub', seed_uuid(2)::text 22 | ); 23 | insert into public.notes(id) values (1); 24 | select clear_wal(); 25 | clear_wal 26 | ----------- 27 | 28 | (1 row) 29 | 30 | update public.notes set body = repeat('a', 5 * 1024 * 1024); 31 | select 32 | rec, 33 | is_rls_enabled, 34 | subscription_ids, 35 | errors 36 | from 37 | walrus; 38 | rec | is_rls_enabled | subscription_ids | errors 39 | ----------------------------------------------------+----------------+----------------------------------------+---------------------------------- 40 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {"Error 413: Payload Too Large"} 41 | "type": "UPDATE", +| | | 42 | "table": "notes", +| | | 43 | "record": { +| | | 44 | "id": 1 +| | | 45 | }, +| | | 46 | "schema": "public", +| | | 47 | "columns": [ +| | | 48 | { +| | | 49 | "name": "id", +| | | 50 | "type": "int4" +| | | 51 | }, +| | | 52 | { +| | | 53 | "name": "body", +| | | 54 | "type": "text" +| | | 55 | } +| | | 56 | ], +| | | 57 | "old_record": { +| | | 58 | "id": 1 +| | | 59 | }, +| | | 60 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 61 | } | | | 62 | (1 row) 63 | 64 | drop table public.notes; 65 | select pg_drop_replication_slot('realtime'); 66 | pg_drop_replication_slot 67 | -------------------------- 68 | 69 | (1 row) 70 | 71 | truncate table realtime.subscription; 72 | -------------------------------------------------------------------------------- /test/expected/test_error_unauthorized.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ?column? 6 | ---------- 7 | 1 8 | (1 row) 9 | 10 | create table public.notes( 11 | id int primary key 12 | ); 13 | revoke select on public.notes from authenticated; 14 | insert into realtime.subscription(subscription_id, entity, claims) 15 | select 16 | seed_uuid(1), 17 | 'public.notes', 18 | jsonb_build_object( 19 | 'role', 'authenticated', 20 | 'email', 'example@example.com', 21 | 'sub', seed_uuid(2)::text 22 | ); 23 | select clear_wal(); 24 | clear_wal 25 | ----------- 26 | 27 | (1 row) 28 | 29 | insert into public.notes(id) values (1); 30 | select 31 | rec, 32 | is_rls_enabled, 33 | subscription_ids, 34 | errors 35 | from 36 | walrus; 37 | rec | is_rls_enabled | subscription_ids | errors 38 | ------------------------+----------------+----------------------------------------+----------------------------- 39 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {"Error 401: Unauthorized"} 40 | "type": "INSERT", +| | | 41 | "table": "notes", +| | | 42 | "schema": "public"+| | | 43 | } | | | 44 | (1 row) 45 | 46 | drop table public.notes; 47 | select pg_drop_replication_slot('realtime'); 48 | pg_drop_replication_slot 49 | -------------------------- 50 | 51 | (1 row) 52 | 53 | truncate table realtime.subscription; 54 | -------------------------------------------------------------------------------- /test/expected/test_integration_filters.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | alter table public.notes replica identity full; 12 | insert into realtime.subscription(subscription_id, entity, claims, filters) 13 | select 14 | seed_uuid(id), 15 | 'public.notes', 16 | jsonb_build_object( 17 | 'role', 'authenticated', 18 | 'email', 'example@example.com', 19 | 'sub', seed_uuid(id)::text 20 | ), 21 | array[(column_name, op, value)::realtime.user_defined_filter] 22 | from 23 | ( 24 | values 25 | (1 , 'body', 'eq', 'bbb'), 26 | (2 , 'body', 'eq', 'aaaa'), 27 | (3 , 'body', 'eq', 'cc') 28 | ) f(id, column_name, op, value); 29 | select clear_wal(); 30 | clear_wal 31 | ----------- 32 | 33 | (1 row) 34 | 35 | insert into public.notes(id, body) values (1, 'bbb'); 36 | delete from public.notes; 37 | select subscription_id, filters from realtime.subscription; 38 | subscription_id | filters 39 | --------------------------------------+-------------------- 40 | f4539ebe-c779-5788-bbc1-2421ffaa8954 | {"(body,eq,bbb)"} 41 | 5211e8ec-8c25-5c7f-9b03-6ff1eac0159e | {"(body,eq,aaaa)"} 42 | 11955172-4e1d-5836-925f-2bcb7a287b87 | {"(body,eq,cc)"} 43 | (3 rows) 44 | 45 | select 46 | rec, 47 | is_rls_enabled, 48 | subscription_ids, 49 | errors 50 | from 51 | walrus; 52 | rec | is_rls_enabled | subscription_ids | errors 53 | ----------------------------------------------------+----------------+----------------------------------------+-------- 54 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 55 | "type": "INSERT", +| | | 56 | "table": "notes", +| | | 57 | "record": { +| | | 58 | "id": 1, +| | | 59 | "body": "bbb" +| | | 60 | }, +| | | 61 | "schema": "public", +| | | 62 | "columns": [ +| | | 63 | { +| | | 64 | "name": "id", +| | | 65 | "type": "int4" +| | | 66 | }, +| | | 67 | { +| | | 68 | "name": "body", +| | | 69 | "type": "text" +| | | 70 | } +| | | 71 | ], +| | | 72 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 73 | } | | | 74 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 75 | "type": "DELETE", +| | | 76 | "table": "notes", +| | | 77 | "schema": "public", +| | | 78 | "columns": [ +| | | 79 | { +| | | 80 | "name": "id", +| | | 81 | "type": "int4" +| | | 82 | }, +| | | 83 | { +| | | 84 | "name": "body", +| | | 85 | "type": "text" +| | | 86 | } +| | | 87 | ], +| | | 88 | "old_record": { +| | | 89 | "id": 1, +| | | 90 | "body": "bbb" +| | | 91 | }, +| | | 92 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 93 | } | | | 94 | (2 rows) 95 | 96 | drop table public.notes; 97 | select pg_drop_replication_slot('realtime'); 98 | pg_drop_replication_slot 99 | -------------------------- 100 | 101 | (1 row) 102 | 103 | truncate table realtime.subscription; 104 | -------------------------------------------------------------------------------- /test/expected/test_integration_in_filter.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | alter table public.notes replica identity full; 12 | insert into realtime.subscription(subscription_id, entity, claims, filters) 13 | select 14 | seed_uuid(id), 15 | 'public.notes', 16 | jsonb_build_object( 17 | 'role', 'authenticated', 18 | 'email', 'example@example.com', 19 | 'sub', seed_uuid(id)::text 20 | ), 21 | array[(column_name, op, value)::realtime.user_defined_filter] 22 | from 23 | ( 24 | values 25 | (1 , 'body', 'in', array['aaa', 'bbb', 'ccc']::text), 26 | (2 , 'body', 'in', array['aaa', 'ccc']::text), 27 | (3 , 'body', 'in', array[]::text[]::text) 28 | ) f(id, column_name, op, value); 29 | select clear_wal(); 30 | clear_wal 31 | ----------- 32 | 33 | (1 row) 34 | 35 | insert into public.notes(id, body) values (1, 'bbb'); 36 | delete from public.notes; 37 | select subscription_id, filters from realtime.subscription; 38 | subscription_id | filters 39 | --------------------------------------+--------------------------------- 40 | f4539ebe-c779-5788-bbc1-2421ffaa8954 | {"(body,in,\"{aaa,bbb,ccc}\")"} 41 | 5211e8ec-8c25-5c7f-9b03-6ff1eac0159e | {"(body,in,\"{aaa,ccc}\")"} 42 | 11955172-4e1d-5836-925f-2bcb7a287b87 | {"(body,in,{})"} 43 | (3 rows) 44 | 45 | select 46 | rec, 47 | is_rls_enabled, 48 | subscription_ids, 49 | errors 50 | from 51 | walrus; 52 | rec | is_rls_enabled | subscription_ids | errors 53 | ----------------------------------------------------+----------------+----------------------------------------+-------- 54 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 55 | "type": "INSERT", +| | | 56 | "table": "notes", +| | | 57 | "record": { +| | | 58 | "id": 1, +| | | 59 | "body": "bbb" +| | | 60 | }, +| | | 61 | "schema": "public", +| | | 62 | "columns": [ +| | | 63 | { +| | | 64 | "name": "id", +| | | 65 | "type": "int4" +| | | 66 | }, +| | | 67 | { +| | | 68 | "name": "body", +| | | 69 | "type": "text" +| | | 70 | } +| | | 71 | ], +| | | 72 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 73 | } | | | 74 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 75 | "type": "DELETE", +| | | 76 | "table": "notes", +| | | 77 | "schema": "public", +| | | 78 | "columns": [ +| | | 79 | { +| | | 80 | "name": "id", +| | | 81 | "type": "int4" +| | | 82 | }, +| | | 83 | { +| | | 84 | "name": "body", +| | | 85 | "type": "text" +| | | 86 | } +| | | 87 | ], +| | | 88 | "old_record": { +| | | 89 | "id": 1, +| | | 90 | "body": "bbb" +| | | 91 | }, +| | | 92 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 93 | } | | | 94 | (2 rows) 95 | 96 | -- Confirm that filtering on `in` more than 100 entries throws an error 97 | insert into realtime.subscription(subscription_id, entity, claims, filters) 98 | select 99 | seed_uuid(6), 100 | 'public.notes', 101 | jsonb_build_object( 102 | 'role', 'authenticated', 103 | 'email', 'example@example.com', 104 | 'sub', seed_uuid(6)::text 105 | ), 106 | array[('body', 'in', array[1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1])::realtime.user_defined_filter]; 107 | ERROR: too many values for `in` filter. Maximum 100 108 | CONTEXT: PL/pgSQL function realtime.subscription_check_filters() line 48 at RAISE 109 | drop table public.notes; 110 | select pg_drop_replication_slot('realtime'); 111 | pg_drop_replication_slot 112 | -------------------------- 113 | 114 | (1 row) 115 | 116 | truncate table realtime.subscription; 117 | -------------------------------------------------------------------------------- /test/expected/test_integration_in_uuid_filter.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | identifier uuid 10 | ); 11 | alter table public.notes replica identity full; 12 | insert into realtime.subscription(subscription_id, entity, claims, filters) 13 | select 14 | seed_uuid(5), 15 | 'public.notes', 16 | jsonb_build_object( 17 | 'role', 'authenticated', 18 | 'email', 'example@example.com', 19 | 'sub', seed_uuid(6)::text 20 | ), 21 | array[( 22 | 'identifier', 23 | 'in', 24 | '{ace23052-568e-4951-acc8-fd510ec667f9,7057e8c3-c05f-4944-b9d9-05f8c45393d1}' 25 | )::realtime.user_defined_filter]; 26 | select clear_wal(); 27 | clear_wal 28 | ----------- 29 | 30 | (1 row) 31 | 32 | insert into public.notes(id, identifier) values (1, 'ace23052-568e-4951-acc8-fd510ec667f9'); 33 | delete from public.notes; 34 | select subscription_id, filters from realtime.subscription; 35 | subscription_id | filters 36 | --------------------------------------+----------------------------------------------------------------------------------------------------- 37 | 3fa85983-bc94-5c16-8bc7-157b8152c678 | {"(identifier,in,\"{ace23052-568e-4951-acc8-fd510ec667f9,7057e8c3-c05f-4944-b9d9-05f8c45393d1}\")"} 38 | (1 row) 39 | 40 | select 41 | rec, 42 | is_rls_enabled, 43 | subscription_ids, 44 | errors 45 | from 46 | walrus; 47 | rec | is_rls_enabled | subscription_ids | errors 48 | --------------------------------------------------------------+----------------+----------------------------------------+-------- 49 | { +| f | {3fa85983-bc94-5c16-8bc7-157b8152c678} | {} 50 | "type": "INSERT", +| | | 51 | "table": "notes", +| | | 52 | "record": { +| | | 53 | "id": 1, +| | | 54 | "identifier": "ace23052-568e-4951-acc8-fd510ec667f9"+| | | 55 | }, +| | | 56 | "schema": "public", +| | | 57 | "columns": [ +| | | 58 | { +| | | 59 | "name": "id", +| | | 60 | "type": "int4" +| | | 61 | }, +| | | 62 | { +| | | 63 | "name": "identifier", +| | | 64 | "type": "uuid" +| | | 65 | } +| | | 66 | ], +| | | 67 | "commit_timestamp": "2000-01-01T08:01:01.000Z" +| | | 68 | } | | | 69 | { +| f | {3fa85983-bc94-5c16-8bc7-157b8152c678} | {} 70 | "type": "DELETE", +| | | 71 | "table": "notes", +| | | 72 | "schema": "public", +| | | 73 | "columns": [ +| | | 74 | { +| | | 75 | "name": "id", +| | | 76 | "type": "int4" +| | | 77 | }, +| | | 78 | { +| | | 79 | "name": "identifier", +| | | 80 | "type": "uuid" +| | | 81 | } +| | | 82 | ], +| | | 83 | "old_record": { +| | | 84 | "id": 1, +| | | 85 | "identifier": "ace23052-568e-4951-acc8-fd510ec667f9"+| | | 86 | }, +| | | 87 | "commit_timestamp": "2000-01-01T08:01:01.000Z" +| | | 88 | } | | | 89 | (2 rows) 90 | 91 | drop table public.notes; 92 | select pg_drop_replication_slot('realtime'); 93 | pg_drop_replication_slot 94 | -------------------------- 95 | 96 | (1 row) 97 | 98 | truncate table realtime.subscription; 99 | -------------------------------------------------------------------------------- /test/expected/test_non_public_schema.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create schema dev; 8 | create table dev.notes( 9 | id int primary key 10 | ); 11 | grant usage on schema dev to authenticated; 12 | grant select on dev.notes to authenticated; 13 | insert into realtime.subscription(subscription_id, entity, claims) 14 | select 15 | seed_uuid(1), 16 | 'dev.notes', 17 | jsonb_build_object( 18 | 'role', 'authenticated', 19 | 'email', 'example@example.com', 20 | 'sub', seed_uuid(1)::text 21 | ); 22 | select clear_wal(); 23 | clear_wal 24 | ----------- 25 | 26 | (1 row) 27 | 28 | insert into dev.notes(id) values (1); 29 | select 30 | rec, 31 | is_rls_enabled, 32 | subscription_ids, 33 | errors 34 | from 35 | walrus; 36 | rec | is_rls_enabled | subscription_ids | errors 37 | ----------------------------------------------------+----------------+----------------------------------------+-------- 38 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 39 | "type": "INSERT", +| | | 40 | "table": "notes", +| | | 41 | "record": { +| | | 42 | "id": 1 +| | | 43 | }, +| | | 44 | "schema": "dev", +| | | 45 | "columns": [ +| | | 46 | { +| | | 47 | "name": "id", +| | | 48 | "type": "int4" +| | | 49 | } +| | | 50 | ], +| | | 51 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 52 | } | | | 53 | (1 row) 54 | 55 | drop table dev.notes; 56 | select pg_drop_replication_slot('realtime'); 57 | pg_drop_replication_slot 58 | -------------------------- 59 | 60 | (1 row) 61 | 62 | truncate table realtime.subscription; 63 | -------------------------------------------------------------------------------- /test/expected/test_old_record_is_primary_key.out: -------------------------------------------------------------------------------- 1 | /* 2 | Test that the "old_record" key for updates (and deletes) contains primary key info 3 | 4 | */ 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | ?column? 7 | ---------- 8 | 1 9 | (1 row) 10 | 11 | create table public.notes( 12 | pk1 int, 13 | pk2 char, 14 | body text, 15 | primary key (pk1, pk2) 16 | ); 17 | insert into realtime.subscription(subscription_id, entity, claims) 18 | select 19 | seed_uuid(1), 20 | 'public.notes', 21 | jsonb_build_object( 22 | 'role', 'authenticated', 23 | 'email', 'example@example.com', 24 | 'sub', seed_uuid(1)::text 25 | ); 26 | insert into public.notes(pk1, pk2, body) values (1, 'a', 'take out trash'); 27 | select clear_wal(); 28 | clear_wal 29 | ----------- 30 | 31 | (1 row) 32 | 33 | update public.notes set pk1 =1; 34 | select 35 | rec, 36 | is_rls_enabled, 37 | subscription_ids, 38 | errors 39 | from 40 | walrus; 41 | rec | is_rls_enabled | subscription_ids | errors 42 | ----------------------------------------------------+----------------+----------------------------------------+-------- 43 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 44 | "type": "UPDATE", +| | | 45 | "table": "notes", +| | | 46 | "record": { +| | | 47 | "pk1": 1, +| | | 48 | "pk2": "a", +| | | 49 | "body": "take out trash" +| | | 50 | }, +| | | 51 | "schema": "public", +| | | 52 | "columns": [ +| | | 53 | { +| | | 54 | "name": "pk1", +| | | 55 | "type": "int4" +| | | 56 | }, +| | | 57 | { +| | | 58 | "name": "pk2", +| | | 59 | "type": "bpchar" +| | | 60 | }, +| | | 61 | { +| | | 62 | "name": "body", +| | | 63 | "type": "text" +| | | 64 | } +| | | 65 | ], +| | | 66 | "old_record": { +| | | 67 | "pk1": 1, +| | | 68 | "pk2": "a" +| | | 69 | }, +| | | 70 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 71 | } | | | 72 | (1 row) 73 | 74 | drop table public.notes; 75 | select pg_drop_replication_slot('realtime'); 76 | pg_drop_replication_slot 77 | -------------------------- 78 | 79 | (1 row) 80 | 81 | truncate table realtime.subscription; 82 | -------------------------------------------------------------------------------- /test/expected/test_old_record_replica_identity_full.out: -------------------------------------------------------------------------------- 1 | /* 2 | Test that the "old_record" key for updates (and deletes) contains all columns 3 | when the replica identity is full 4 | 5 | */ 6 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 7 | ?column? 8 | ---------- 9 | 1 10 | (1 row) 11 | 12 | create table public.notes( 13 | pk1 int, 14 | pk2 char, 15 | body text, 16 | primary key (pk1, pk2) 17 | ); 18 | alter table public.notes replica identity full; 19 | insert into realtime.subscription(subscription_id, entity, claims) 20 | select 21 | seed_uuid(1), 22 | 'public.notes', 23 | jsonb_build_object( 24 | 'role', 'authenticated', 25 | 'email', 'example@example.com', 26 | 'sub', seed_uuid(1)::text 27 | ); 28 | insert into public.notes(pk1, pk2, body) values (1, 'a', 'take out trash'); 29 | select clear_wal(); 30 | clear_wal 31 | ----------- 32 | 33 | (1 row) 34 | 35 | update public.notes set pk1 =1; 36 | select 37 | rec, 38 | is_rls_enabled, 39 | subscription_ids, 40 | errors 41 | from 42 | walrus; 43 | rec | is_rls_enabled | subscription_ids | errors 44 | ----------------------------------------------------+----------------+----------------------------------------+-------- 45 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 46 | "type": "UPDATE", +| | | 47 | "table": "notes", +| | | 48 | "record": { +| | | 49 | "pk1": 1, +| | | 50 | "pk2": "a", +| | | 51 | "body": "take out trash" +| | | 52 | }, +| | | 53 | "schema": "public", +| | | 54 | "columns": [ +| | | 55 | { +| | | 56 | "name": "pk1", +| | | 57 | "type": "int4" +| | | 58 | }, +| | | 59 | { +| | | 60 | "name": "pk2", +| | | 61 | "type": "bpchar" +| | | 62 | }, +| | | 63 | { +| | | 64 | "name": "body", +| | | 65 | "type": "text" +| | | 66 | } +| | | 67 | ], +| | | 68 | "old_record": { +| | | 69 | "pk1": 1, +| | | 70 | "pk2": "a", +| | | 71 | "body": "take out trash" +| | | 72 | }, +| | | 73 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 74 | } | | | 75 | (1 row) 76 | 77 | drop table public.notes; 78 | select pg_drop_replication_slot('realtime'); 79 | pg_drop_replication_slot 80 | -------------------------- 81 | 82 | (1 row) 83 | 84 | truncate table realtime.subscription; 85 | -------------------------------------------------------------------------------- /test/expected/test_query_from_publication.out: -------------------------------------------------------------------------------- 1 | /* 2 | Test that only tables in the publication are selected by the polling_query view 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ?column? 6 | ---------- 7 | 1 8 | (1 row) 9 | 10 | create table public.notes( 11 | id int primary key, 12 | user_id uuid 13 | ); 14 | create table public.not_in_pub( 15 | id int primary key 16 | ); 17 | drop publication supabase_realtime; 18 | create publication 19 | supabase_realtime 20 | for table 21 | public.notes 22 | with ( 23 | publish = 'insert,update,delete' 24 | ); 25 | insert into realtime.subscription(subscription_id, entity, claims) 26 | select 27 | seed_uuid(1), 28 | 'public.notes', 29 | jsonb_build_object( 30 | 'role', 'authenticated', 31 | 'email', 'example@example.com', 32 | 'sub', seed_uuid(1)::text 33 | ); 34 | insert into realtime.subscription(subscription_id, entity, claims) 35 | select 36 | seed_uuid(1), 37 | 'public.not_in_pub', 38 | jsonb_build_object( 39 | 'role', 'authenticated', 40 | 'email', 'example@example.com', 41 | 'sub', seed_uuid(1)::text 42 | ); 43 | select clear_wal(); 44 | clear_wal 45 | ----------- 46 | 47 | (1 row) 48 | 49 | insert into public.notes(id) values (1); 50 | insert into public.not_in_pub(id) values (1); 51 | select pubname, schemaname, tablename, attnames from pg_publication_tables; 52 | pubname | schemaname | tablename | attnames 53 | -------------------+------------+-----------+-------------- 54 | supabase_realtime | public | notes | {id,user_id} 55 | (1 row) 56 | 57 | select 58 | jsonb_pretty(wal - 'commit_timestamp'), 59 | is_rls_enabled, 60 | subscription_ids, 61 | errors 62 | from 63 | polling_query; 64 | jsonb_pretty | is_rls_enabled | subscription_ids | errors 65 | --------------------------------+----------------+----------------------------------------+-------- 66 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 67 | "type": "INSERT", +| | | 68 | "table": "notes", +| | | 69 | "record": { +| | | 70 | "id": 1, +| | | 71 | "user_id": null +| | | 72 | }, +| | | 73 | "schema": "public", +| | | 74 | "columns": [ +| | | 75 | { +| | | 76 | "name": "id", +| | | 77 | "type": "int4" +| | | 78 | }, +| | | 79 | { +| | | 80 | "name": "user_id",+| | | 81 | "type": "uuid" +| | | 82 | } +| | | 83 | ] +| | | 84 | } | | | 85 | (1 row) 86 | 87 | drop table public.not_in_pub; 88 | drop table public.notes; 89 | truncate table realtime.subscription; 90 | drop publication supabase_realtime; 91 | -------------------------------------------------------------------------------- /test/expected/test_rls_skips_subscriber.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that subscriber is omitted when record not visible to them in the RLS policy 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | ERROR: replication slot "realtime" already exists 6 | create table public.notes( 7 | id int primary key, 8 | user_id uuid 9 | ); 10 | create policy rls_note_select 11 | on public.notes 12 | to authenticated 13 | using (user_id = auth.uid()); 14 | alter table public.notes enable row level security; 15 | insert into realtime.subscription(subscription_id, entity, claims) 16 | select 17 | seed_uuid(1), -- matches for convienence, not required, 18 | 'public.notes', 19 | jsonb_build_object( 20 | 'role', 'authenticated', 21 | 'email', 'example@example.com', 22 | 'sub', seed_uuid(1)::text -- should see result according to RLS 23 | ); 24 | insert into realtime.subscription(subscription_id, entity, claims) 25 | select 26 | seed_uuid(2), -- matches for convienence, not required, 27 | 'public.notes', 28 | jsonb_build_object( 29 | 'role', 'authenticated', 30 | 'email', 'example@example.com', 31 | 'sub', seed_uuid(2)::text -- should NOT see result 32 | ); 33 | select clear_wal(); 34 | clear_wal 35 | ----------- 36 | 37 | (1 row) 38 | 39 | insert into public.notes(id, user_id) values (1, seed_uuid(1)); 40 | begin; 41 | select 42 | -- set an auth.uid() to seed_uuid(1) 43 | set_config( 44 | 'request.jwt.claims', 45 | jsonb_build_object( 46 | 'role', 'authenticated', 47 | 'email', 'example@example.com', 48 | 'sub', seed_uuid(1)::text 49 | )::text, 50 | true 51 | ); 52 | set_config 53 | ---------------------------------------------------------------------------------------------------------- 54 | {"sub": "f4539ebe-c779-5788-bbc1-2421ffaa8954", "role": "authenticated", "email": "example@example.com"} 55 | (1 row) 56 | 57 | select auth.uid(); 58 | uid 59 | -------------------------------------- 60 | f4539ebe-c779-5788-bbc1-2421ffaa8954 61 | (1 row) 62 | 63 | -- Expect 1 entry in the subscriber array matching ^ 64 | select 65 | rec, 66 | is_rls_enabled, 67 | subscription_ids, 68 | errors 69 | from 70 | walrus; 71 | rec | is_rls_enabled | subscription_ids | errors 72 | -----------------------------------------------------------+----------------+----------------------------------------+-------- 73 | { +| t | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 74 | "type": "INSERT", +| | | 75 | "table": "notes", +| | | 76 | "record": { +| | | 77 | "id": 1, +| | | 78 | "user_id": "f4539ebe-c779-5788-bbc1-2421ffaa8954"+| | | 79 | }, +| | | 80 | "schema": "public", +| | | 81 | "columns": [ +| | | 82 | { +| | | 83 | "name": "id", +| | | 84 | "type": "int4" +| | | 85 | }, +| | | 86 | { +| | | 87 | "name": "user_id", +| | | 88 | "type": "uuid" +| | | 89 | } +| | | 90 | ], +| | | 91 | "commit_timestamp": "2000-01-01T08:01:01.000Z" +| | | 92 | } | | | 93 | (1 row) 94 | 95 | end; 96 | drop table public.notes; 97 | select pg_drop_replication_slot('realtime'); 98 | pg_drop_replication_slot 99 | -------------------------- 100 | 101 | (1 row) 102 | 103 | truncate table realtime.subscription; 104 | -------------------------------------------------------------------------------- /test/expected/test_role_with_hyphen.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create role "has-hyphen" nologin noinherit; 8 | create schema private; 9 | grant usage on schema private to "has-hyphen"; 10 | alter default privileges in schema private grant all on tables to "has-hyphen"; 11 | alter default privileges in schema private grant all on functions to "has-hyphen"; 12 | alter default privileges in schema private grant all on sequences to "has-hyphen"; 13 | create table private.notes( 14 | id int primary key 15 | ); 16 | create policy rls_note_select 17 | on private.notes 18 | to "has-hyphen" 19 | using (true); 20 | alter table private.notes enable row level security; 21 | insert into realtime.subscription(subscription_id, entity, claims) 22 | select 23 | seed_uuid(1), 24 | 'private.notes', 25 | jsonb_build_object( 26 | 'role', 'has-hyphen', 27 | 'email', 'example@example.com', 28 | 'sub', seed_uuid(1)::text 29 | ); 30 | select clear_wal(); 31 | clear_wal 32 | ----------- 33 | 34 | (1 row) 35 | 36 | insert into private.notes(id) values (1); 37 | select 38 | rec, 39 | is_rls_enabled, 40 | subscription_ids, 41 | errors 42 | from 43 | walrus; 44 | rec | is_rls_enabled | subscription_ids | errors 45 | ----------------------------------------------------+----------------+----------------------------------------+-------- 46 | { +| t | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 47 | "type": "INSERT", +| | | 48 | "table": "notes", +| | | 49 | "record": { +| | | 50 | "id": 1 +| | | 51 | }, +| | | 52 | "schema": "private", +| | | 53 | "columns": [ +| | | 54 | { +| | | 55 | "name": "id", +| | | 56 | "type": "int4" +| | | 57 | } +| | | 58 | ], +| | | 59 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 60 | } | | | 61 | (1 row) 62 | 63 | drop table private.notes; 64 | drop schema private; 65 | select pg_drop_replication_slot('realtime'); 66 | pg_drop_replication_slot 67 | -------------------------- 68 | 69 | (1 row) 70 | 71 | truncate table realtime.subscription; 72 | -------------------------------------------------------------------------------- /test/expected/test_select_one.out: -------------------------------------------------------------------------------- 1 | select 1; 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | -------------------------------------------------------------------------------- /test/expected/test_simple_delete.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | insert into realtime.subscription(subscription_id, entity, claims) 12 | select 13 | seed_uuid(1), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(1)::text 19 | ); 20 | insert into public.notes(id, body) values (1, 'take out trash'); 21 | select clear_wal(); 22 | clear_wal 23 | ----------- 24 | 25 | (1 row) 26 | 27 | delete from public.notes; 28 | select 29 | rec, 30 | is_rls_enabled, 31 | subscription_ids, 32 | errors 33 | from 34 | walrus; 35 | rec | is_rls_enabled | subscription_ids | errors 36 | ----------------------------------------------------+----------------+----------------------------------------+-------- 37 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 38 | "type": "DELETE", +| | | 39 | "table": "notes", +| | | 40 | "schema": "public", +| | | 41 | "columns": [ +| | | 42 | { +| | | 43 | "name": "id", +| | | 44 | "type": "int4" +| | | 45 | }, +| | | 46 | { +| | | 47 | "name": "body", +| | | 48 | "type": "text" +| | | 49 | } +| | | 50 | ], +| | | 51 | "old_record": { +| | | 52 | "id": 1 +| | | 53 | }, +| | | 54 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 55 | } | | | 56 | (1 row) 57 | 58 | drop table public.notes; 59 | select pg_drop_replication_slot('realtime'); 60 | pg_drop_replication_slot 61 | -------------------------- 62 | 63 | (1 row) 64 | 65 | truncate table realtime.subscription; 66 | -------------------------------------------------------------------------------- /test/expected/test_simple_insert.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key 9 | ); 10 | insert into realtime.subscription(subscription_id, entity, claims) 11 | select 12 | seed_uuid(1), 13 | 'public.notes', 14 | jsonb_build_object( 15 | 'role', 'authenticated', 16 | 'email', 'example@example.com', 17 | 'sub', seed_uuid(1)::text 18 | ); 19 | select clear_wal(); 20 | clear_wal 21 | ----------- 22 | 23 | (1 row) 24 | 25 | insert into public.notes(id) values (1); 26 | select 27 | rec, 28 | is_rls_enabled, 29 | subscription_ids, 30 | errors 31 | from 32 | walrus; 33 | rec | is_rls_enabled | subscription_ids | errors 34 | ----------------------------------------------------+----------------+----------------------------------------+-------- 35 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 36 | "type": "INSERT", +| | | 37 | "table": "notes", +| | | 38 | "record": { +| | | 39 | "id": 1 +| | | 40 | }, +| | | 41 | "schema": "public", +| | | 42 | "columns": [ +| | | 43 | { +| | | 44 | "name": "id", +| | | 45 | "type": "int4" +| | | 46 | } +| | | 47 | ], +| | | 48 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 49 | } | | | 50 | (1 row) 51 | 52 | drop table public.notes; 53 | select pg_drop_replication_slot('realtime'); 54 | pg_drop_replication_slot 55 | -------------------------- 56 | 57 | (1 row) 58 | 59 | truncate table realtime.subscription; 60 | -------------------------------------------------------------------------------- /test/expected/test_simple_update.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | insert into realtime.subscription(subscription_id, entity, claims) 12 | select 13 | seed_uuid(1), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(1)::text 19 | ); 20 | insert into public.notes(id, body) values (1, 'take out trash'); 21 | select clear_wal(); 22 | clear_wal 23 | ----------- 24 | 25 | (1 row) 26 | 27 | update public.notes set id=2; 28 | select 29 | rec, 30 | is_rls_enabled, 31 | subscription_ids, 32 | errors 33 | from 34 | walrus; 35 | rec | is_rls_enabled | subscription_ids | errors 36 | ----------------------------------------------------+----------------+----------------------------------------+-------- 37 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 38 | "type": "UPDATE", +| | | 39 | "table": "notes", +| | | 40 | "record": { +| | | 41 | "id": 2, +| | | 42 | "body": "take out trash" +| | | 43 | }, +| | | 44 | "schema": "public", +| | | 45 | "columns": [ +| | | 46 | { +| | | 47 | "name": "id", +| | | 48 | "type": "int4" +| | | 49 | }, +| | | 50 | { +| | | 51 | "name": "body", +| | | 52 | "type": "text" +| | | 53 | } +| | | 54 | ], +| | | 55 | "old_record": { +| | | 56 | "id": 1 +| | | 57 | }, +| | | 58 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 59 | } | | | 60 | (1 row) 61 | 62 | drop table public.notes; 63 | select pg_drop_replication_slot('realtime'); 64 | pg_drop_replication_slot 65 | -------------------------- 66 | 67 | (1 row) 68 | 69 | truncate table realtime.subscription; 70 | -------------------------------------------------------------------------------- /test/expected/test_subscribers_multiple_roles.out: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that when multiple roles are subscribed to the same table, a WAL record 3 | is split into 2 rows so permissions can be handled independently 4 | 5 | The authenticated role has limited access to `public.notes` and has one field 6 | redacted in the output. 7 | */ 8 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 9 | ?column? 10 | ---------- 11 | 1 12 | (1 row) 13 | 14 | create table public.notes( 15 | id int primary key, 16 | body text 17 | ); 18 | revoke select on public.notes from authenticated; 19 | grant select (id) on public.notes to authenticated; 20 | insert into realtime.subscription(subscription_id, entity, claims) 21 | select 22 | seed_uuid(a.ix::int), 23 | 'public.notes', 24 | jsonb_build_object( 25 | 'role', role_name, 26 | 'email', 'example@example.com', 27 | 'sub', seed_uuid(3)::text 28 | ) 29 | from 30 | unnest( 31 | array['authenticated', 'postgres'] 32 | ) with ordinality a(role_name, ix); 33 | insert into public.notes(id, body) values (1, 'hello'); 34 | select 35 | rec, 36 | is_rls_enabled, 37 | subscription_ids, 38 | errors 39 | from 40 | walrus; 41 | rec | is_rls_enabled | subscription_ids | errors 42 | ----------------------------------------------------+----------------+----------------------------------------+-------- 43 | { +| f | {f4539ebe-c779-5788-bbc1-2421ffaa8954} | {} 44 | "type": "INSERT", +| | | 45 | "table": "notes", +| | | 46 | "record": { +| | | 47 | "id": 1 +| | | 48 | }, +| | | 49 | "schema": "public", +| | | 50 | "columns": [ +| | | 51 | { +| | | 52 | "name": "id", +| | | 53 | "type": "int4" +| | | 54 | } +| | | 55 | ], +| | | 56 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 57 | } | | | 58 | { +| f | {5211e8ec-8c25-5c7f-9b03-6ff1eac0159e} | {} 59 | "type": "INSERT", +| | | 60 | "table": "notes", +| | | 61 | "record": { +| | | 62 | "id": 1, +| | | 63 | "body": "hello" +| | | 64 | }, +| | | 65 | "schema": "public", +| | | 66 | "columns": [ +| | | 67 | { +| | | 68 | "name": "id", +| | | 69 | "type": "int4" +| | | 70 | }, +| | | 71 | { +| | | 72 | "name": "body", +| | | 73 | "type": "text" +| | | 74 | } +| | | 75 | ], +| | | 76 | "commit_timestamp": "2000-01-01T08:01:01.000Z"+| | | 77 | } | | | 78 | (2 rows) 79 | 80 | drop table public.notes; 81 | select pg_drop_replication_slot('realtime'); 82 | pg_drop_replication_slot 83 | -------------------------- 84 | 85 | (1 row) 86 | 87 | truncate table realtime.subscription; 88 | -------------------------------------------------------------------------------- /test/expected/test_unit_filters.out: -------------------------------------------------------------------------------- 1 | select realtime.check_equality_op('eq', 'text', 'aaa', 'aaa'); 2 | check_equality_op 3 | ------------------- 4 | t 5 | (1 row) 6 | 7 | select realtime.check_equality_op('eq', 'text', 'aaa', 'bbb'); 8 | check_equality_op 9 | ------------------- 10 | f 11 | (1 row) 12 | 13 | select realtime.check_equality_op('neq', 'text', 'aaa', 'aaa'); 14 | check_equality_op 15 | ------------------- 16 | f 17 | (1 row) 18 | 19 | select realtime.check_equality_op('neq', 'text', 'aaa', 'bbb'); 20 | check_equality_op 21 | ------------------- 22 | t 23 | (1 row) 24 | 25 | select realtime.check_equality_op('lt', 'text', 'aaa', 'bbb'); 26 | check_equality_op 27 | ------------------- 28 | t 29 | (1 row) 30 | 31 | select realtime.check_equality_op('lt', 'text', 'bbb', 'aaa'); 32 | check_equality_op 33 | ------------------- 34 | f 35 | (1 row) 36 | 37 | select realtime.check_equality_op('lt', 'text', 'bbb', 'bbb'); 38 | check_equality_op 39 | ------------------- 40 | f 41 | (1 row) 42 | 43 | select realtime.check_equality_op('lte', 'text', 'aaa', 'bbb'); 44 | check_equality_op 45 | ------------------- 46 | t 47 | (1 row) 48 | 49 | select realtime.check_equality_op('lte', 'text', 'bbb', 'aaa'); 50 | check_equality_op 51 | ------------------- 52 | f 53 | (1 row) 54 | 55 | select realtime.check_equality_op('lte', 'text', 'bbb', 'bbb'); 56 | check_equality_op 57 | ------------------- 58 | t 59 | (1 row) 60 | 61 | select realtime.check_equality_op('gt', 'text', 'aaa', 'bbb'); 62 | check_equality_op 63 | ------------------- 64 | f 65 | (1 row) 66 | 67 | select realtime.check_equality_op('gt', 'text', 'bbb', 'aaa'); 68 | check_equality_op 69 | ------------------- 70 | t 71 | (1 row) 72 | 73 | select realtime.check_equality_op('gt', 'text', 'bbb', 'bbb'); 74 | check_equality_op 75 | ------------------- 76 | f 77 | (1 row) 78 | 79 | select realtime.check_equality_op('gte', 'text', 'aaa', 'bbb'); 80 | check_equality_op 81 | ------------------- 82 | f 83 | (1 row) 84 | 85 | select realtime.check_equality_op('gte', 'text', 'bbb', 'aaa'); 86 | check_equality_op 87 | ------------------- 88 | t 89 | (1 row) 90 | 91 | select realtime.check_equality_op('gte', 'text', 'bbb', 'bbb'); 92 | check_equality_op 93 | ------------------- 94 | t 95 | (1 row) 96 | 97 | select realtime.check_equality_op('eq', 'bigint', '1', '1'); 98 | check_equality_op 99 | ------------------- 100 | t 101 | (1 row) 102 | 103 | select realtime.check_equality_op('eq', 'bigint', '2', '1'); 104 | check_equality_op 105 | ------------------- 106 | f 107 | (1 row) 108 | 109 | select realtime.check_equality_op('eq', 'bigint', '2', null); 110 | check_equality_op 111 | ------------------- 112 | 113 | (1 row) 114 | 115 | select realtime.check_equality_op('eq','uuid','639f86b1-738b-43ed-bb09-c8d3f3bafa30','639f86b1-738b-43ed-bb09-c8d3f3bafa30'); 116 | check_equality_op 117 | ------------------- 118 | t 119 | (1 row) 120 | 121 | select realtime.check_equality_op('eq','uuid','639f86b1-738b-43ed-bb09-c8d3f3bafa30','b423f213-ac24-402a-95ea-cf1d94d8e9f0'); 122 | check_equality_op 123 | ------------------- 124 | f 125 | (1 row) 126 | 127 | select realtime.check_equality_op('in', 'bigint', '2', '{1,2,3}'); 128 | check_equality_op 129 | ------------------- 130 | t 131 | (1 row) 132 | 133 | select realtime.check_equality_op('in', 'bigint', '4', '{1,2,3}'); 134 | check_equality_op 135 | ------------------- 136 | f 137 | (1 row) 138 | 139 | -------------------------------------------------------------------------------- /test/expected/test_wal2json_output.out: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | ?column? 3 | ---------- 4 | 1 5 | (1 row) 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | begin; 12 | insert into public.notes(id, body) values (1, 'hello'); 13 | update public.notes set body = 'world'; 14 | delete from public.notes; 15 | end; 16 | select 17 | jsonb_pretty(norm(x.data::jsonb)) 18 | from 19 | pg_logical_slot_get_changes( 20 | 'realtime', null, null, 21 | 'include-pk', '1', 22 | 'include-transaction', 'false', 23 | 'include-timestamp', 'true', 24 | 'include-type-oids', 'true', 25 | 'format-version', '2', 26 | 'actions', 'insert,update,delete', 27 | 'add-tables', 'public.notes' 28 | ) x; 29 | jsonb_pretty 30 | -------------------------------------------------- 31 | { + 32 | "pk": [ + 33 | { + 34 | "name": "id", + 35 | "type": "integer", + 36 | "typeoid": 23 + 37 | } + 38 | ], + 39 | "table": "notes", + 40 | "action": "I", + 41 | "schema": "public", + 42 | "columns": [ + 43 | { + 44 | "name": "id", + 45 | "type": "integer", + 46 | "value": 1, + 47 | "typeoid": 23 + 48 | }, + 49 | { + 50 | "name": "body", + 51 | "type": "text", + 52 | "value": "hello", + 53 | "typeoid": 25 + 54 | } + 55 | ], + 56 | "timestamp": "2000-01-01 01:01:01.000000-07"+ 57 | } 58 | { + 59 | "pk": [ + 60 | { + 61 | "name": "id", + 62 | "type": "integer", + 63 | "typeoid": 23 + 64 | } + 65 | ], + 66 | "table": "notes", + 67 | "action": "U", + 68 | "schema": "public", + 69 | "columns": [ + 70 | { + 71 | "name": "id", + 72 | "type": "integer", + 73 | "value": 1, + 74 | "typeoid": 23 + 75 | }, + 76 | { + 77 | "name": "body", + 78 | "type": "text", + 79 | "value": "world", + 80 | "typeoid": 25 + 81 | } + 82 | ], + 83 | "identity": [ + 84 | { + 85 | "name": "id", + 86 | "type": "integer", + 87 | "value": 1, + 88 | "typeoid": 23 + 89 | } + 90 | ], + 91 | "timestamp": "2000-01-01 01:01:01.000000-07"+ 92 | } 93 | { + 94 | "pk": [ + 95 | { + 96 | "name": "id", + 97 | "type": "integer", + 98 | "typeoid": 23 + 99 | } + 100 | ], + 101 | "table": "notes", + 102 | "action": "D", + 103 | "schema": "public", + 104 | "identity": [ + 105 | { + 106 | "name": "id", + 107 | "type": "integer", + 108 | "value": 1, + 109 | "typeoid": 23 + 110 | } + 111 | ], + 112 | "timestamp": "2000-01-01 01:01:01.000000-07"+ 113 | } 114 | (3 rows) 115 | 116 | select pg_drop_replication_slot('realtime'); 117 | pg_drop_replication_slot 118 | -------------------------- 119 | 120 | (1 row) 121 | 122 | drop table public.notes; 123 | truncate table realtime.subscription; 124 | -------------------------------------------------------------------------------- /test/fixtures.sql: -------------------------------------------------------------------------------- 1 | set timezone to 'UTC'; 2 | alter database contrib_regression set timezone to 'UTC'; 3 | 4 | create function norm(jsonb) returns jsonb 5 | language sql 6 | strict 7 | as $$ 8 | -- Normalizes timestamps and pretty prints 9 | select 10 | regexp_replace( 11 | $1::text, 12 | '\d{4}-\d{2}-\d{2} \d{2}:\d{2}:\d{2}.\d+-\d+', 13 | '2000-01-01 01:01:01.000000-07', 14 | 'g' 15 | )::jsonb 16 | $$; 17 | 18 | 19 | create function clear_wal() returns void 20 | language plpgsql 21 | as $$ 22 | begin 23 | perform pg_logical_slot_get_changes('realtime', null, null); 24 | end; 25 | $$; 26 | 27 | 28 | create view walrus as 29 | select 30 | jsonb_pretty(norm(x.data::jsonb)) w2j_data, 31 | jsonb_pretty(xyz.wal) rec, 32 | xyz.is_rls_enabled, 33 | xyz.subscription_ids, 34 | xyz.errors 35 | from 36 | pg_logical_slot_get_changes( 37 | 'realtime', null, null, 38 | 'include-pk', '1', 39 | 'include-transaction', 'false', 40 | 'include-timestamp', 'true', 41 | 'include-type-oids', 'true', 42 | 'format-version', '2', 43 | 'actions', 'insert,update,delete' 44 | ) x, 45 | lateral ( 46 | select 47 | * 48 | from 49 | realtime.apply_rls( 50 | wal := norm(x.data::jsonb), 51 | max_record_bytes := 1048576 52 | ) 53 | ) xyz(wal, is_rls_enabled, subscription_ids, errors); 54 | 55 | 56 | create function seed_uuid(seed int) 57 | returns uuid 58 | language sql 59 | as $$ 60 | select 61 | extensions.uuid_generate_v5( 62 | 'fd62bc3d-8d6e-43c2-919c-802ba3762271', 63 | seed::text 64 | ) 65 | $$; 66 | 67 | 68 | 69 | -- This is the query used for polling for changes while respecting a publication 70 | create view polling_query as 71 | with pub as ( 72 | select 73 | concat_ws( 74 | ',', 75 | case when bool_or(pubinsert) then 'insert' else null end, 76 | case when bool_or(pubupdate) then 'update' else null end, 77 | case when bool_or(pubdelete) then 'delete' else null end 78 | ) as w2j_actions, 79 | coalesce( 80 | string_agg( 81 | realtime.quote_wal2json(format('%I.%I', schemaname, tablename)::regclass), 82 | ',' 83 | ) filter (where ppt.tablename is not null), 84 | '' 85 | ) w2j_add_tables 86 | from 87 | pg_publication pp 88 | left join pg_publication_tables ppt 89 | on pp.pubname = ppt.pubname 90 | where 91 | pp.pubname = 'supabase_realtime' 92 | group by 93 | pp.pubname 94 | limit 1 95 | ), 96 | w2j as ( 97 | select 98 | x.*, pub.w2j_add_tables 99 | from 100 | pub, -- always returns 1 row. possibly null entries 101 | pg_logical_slot_get_changes( 102 | 'realtime', null, null, 103 | 'include-pk', '1', 104 | 'include-transaction', 'false', 105 | 'include-type-oids', 'true', 106 | 'include-timestamp', 'true', 107 | 'write-in-chunks', 'true', 108 | 'format-version', '2', 109 | 'actions', pub.w2j_actions, 110 | 'add-tables', pub.w2j_add_tables 111 | ) x 112 | ) 113 | select 114 | xyz.wal, 115 | xyz.is_rls_enabled, 116 | xyz.subscription_ids, 117 | xyz.errors 118 | from 119 | w2j, 120 | realtime.apply_rls( 121 | wal := w2j.data::jsonb, 122 | max_record_bytes := 1048576 123 | ) xyz(wal, is_rls_enabled, subscription_ids, errors) 124 | where 125 | -- filter from w2j instead of pub to force `pg_logical_get_slots` to be called 126 | w2j.w2j_add_tables <> '' 127 | and xyz.subscription_ids[1] is not null 128 | -------------------------------------------------------------------------------- /test/sql/issue_40_quoted_regtype.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that, regtypes that require quoting are handled without exception 3 | */ 4 | 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | 8 | create type "Color" as enum ('RED', 'YELLOW', 'GREEN'); 9 | 10 | create table public.notes( 11 | id int primary key, 12 | primary_color "Color" 13 | ); 14 | 15 | 16 | create policy rls_color_is_red 17 | on public.notes 18 | to authenticated 19 | using (primary_color = 'RED'); 20 | 21 | alter table public.notes enable row level security; 22 | 23 | 24 | insert into realtime.subscription(subscription_id, entity, claims, filters) 25 | select 26 | seed_uuid(1), 27 | 'public.notes', 28 | jsonb_build_object( 29 | 'role', 'authenticated', 30 | 'sub', seed_uuid(2)::text 31 | ), 32 | array[('primary_color', 'eq', 'RED')::realtime.user_defined_filter]; 33 | 34 | insert into public.notes(id, primary_color) 35 | values 36 | (1, 'RED'), -- matches filter 37 | (2, 'GREEN'); -- does not match filter 38 | 39 | select 40 | rec, 41 | is_rls_enabled, 42 | subscription_ids, 43 | errors 44 | from 45 | walrus; 46 | 47 | 48 | drop table public.notes; 49 | select pg_drop_replication_slot('realtime'); 50 | truncate table realtime.subscription; 51 | -------------------------------------------------------------------------------- /test/sql/issue_50_delete_filters.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | insert into realtime.subscription(subscription_id, entity, claims, filters) 9 | select 10 | seed_uuid(id), 11 | 'public.notes', 12 | jsonb_build_object( 13 | 'role', 'authenticated', 14 | 'email', 'example@example.com', 15 | 'sub', seed_uuid(id)::text 16 | ), 17 | array[(column_name, op, value)::realtime.user_defined_filter] 18 | from 19 | ( 20 | values 21 | (1 , 'body', 'eq', 'bbb'), 22 | (2 , 'id', 'eq', '2') 23 | 24 | ) f(id, column_name, op, value); 25 | 26 | select subscription_id, filters from realtime.subscription; 27 | 28 | ---------------------------------------------------------------------------------------- 29 | -- When Replica Identity is Not Full, only filters referencing the pkey are respected -- 30 | ---------------------------------------------------------------------------------------- 31 | 32 | insert into public.notes(id, body) 33 | values 34 | (1, 'bbb'), 35 | (2, 'ccc'); 36 | 37 | select clear_wal(); 38 | 39 | delete from public.notes; 40 | 41 | 42 | select 43 | rec, 44 | is_rls_enabled, 45 | subscription_ids, 46 | errors 47 | from 48 | walrus; 49 | 50 | 51 | ---------------------------------------------------------------------------------------- 52 | -- When Replica Identity is Not Full, only filters referencing the pkey are respected -- 53 | ---------------------------------------------------------------------------------------- 54 | 55 | alter table public.notes replica identity full; 56 | 57 | insert into public.notes(id, body) 58 | values 59 | (1, 'bbb'), 60 | (2, 'ccc'); 61 | 62 | select clear_wal(); 63 | 64 | delete from public.notes; 65 | 66 | 67 | select 68 | rec, 69 | is_rls_enabled, 70 | subscription_ids, 71 | errors 72 | from 73 | walrus; 74 | 75 | 76 | drop table public.notes; 77 | select pg_drop_replication_slot('realtime'); 78 | truncate table realtime.subscription; 79 | -------------------------------------------------------------------------------- /test/sql/issue_55_null_passes_filters.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id serial primary key, 5 | page_id int 6 | ); 7 | 8 | insert into realtime.subscription(subscription_id, entity, claims, filters) 9 | select 10 | seed_uuid(1), 11 | 'public.notes', 12 | jsonb_build_object( 13 | 'role', 'authenticated', 14 | 'email', 'example@example.com', 15 | 'sub', seed_uuid(1)::text 16 | ), 17 | array[('page_id', 'eq', '5')::realtime.user_defined_filter]; 18 | 19 | select clear_wal(); 20 | 21 | 22 | -- Expect 0 subscriptions: filters do not match: 5 <> 1 23 | insert into public.notes(page_id) values (1); 24 | select 25 | rec, 26 | is_rls_enabled, 27 | subscription_ids, 28 | errors 29 | from 30 | walrus; 31 | 32 | 33 | 34 | -- Expect 1 subscription: filters do match 5 = 5 35 | insert into public.notes(page_id) values (5); 36 | select 37 | rec, 38 | is_rls_enabled, 39 | subscription_ids, 40 | errors 41 | from 42 | walrus; 43 | 44 | 45 | 46 | -- Expect 0 subscriptions: filters do match 5 <> null 47 | insert into public.notes(page_id) values (null); 48 | select 49 | rec, 50 | is_rls_enabled, 51 | subscription_ids, 52 | errors 53 | from 54 | walrus; 55 | 56 | 57 | 58 | drop table public.notes; 59 | select pg_drop_replication_slot('realtime'); 60 | truncate table realtime.subscription; 61 | -------------------------------------------------------------------------------- /test/sql/test_column_permissions_hide_columns.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that, when a role does not have select access to a column, it is omitted 3 | from realtime output 4 | 5 | In this case, we omit the "body" column 6 | */ 7 | 8 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 9 | 10 | create table public.notes( 11 | id int primary key, 12 | body text 13 | ); 14 | 15 | revoke select on public.notes from authenticated; 16 | grant select (id) on public.notes to authenticated; 17 | 18 | 19 | insert into realtime.subscription(subscription_id, entity, claims) 20 | select 21 | seed_uuid(1), 22 | 'public.notes', 23 | jsonb_build_object( 24 | 'role', 'authenticated', 25 | 'sub', seed_uuid(2)::text 26 | ); 27 | 28 | 29 | insert into public.notes(id, body) values (1, 'hello'); 30 | 31 | select 32 | rec, 33 | is_rls_enabled, 34 | subscription_ids, 35 | errors 36 | from 37 | walrus; 38 | 39 | 40 | drop table public.notes; 41 | select pg_drop_replication_slot('realtime'); 42 | truncate table realtime.subscription; 43 | -------------------------------------------------------------------------------- /test/sql/test_delete_old_record_behavior.sql: -------------------------------------------------------------------------------- 1 | /* 2 | 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | 6 | create table public.notes( 7 | pk1 int primary key, 8 | body text 9 | ); 10 | 11 | insert into realtime.subscription(subscription_id, entity, claims) 12 | select 13 | seed_uuid(1), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(1)::text 19 | ); 20 | 21 | -- Option 1: 22 | -- Replica Identity Full: false 23 | -- Row Level Security : false 24 | 25 | -- Expect: 26 | -- old_record contains only primary key info because only pkey info available in WAL 27 | alter table public.notes replica identity default; 28 | alter table public.notes disable row level security; 29 | insert into public.notes(pk1, body) values (1, 'take out trash'); 30 | select clear_wal(); 31 | delete from public.notes where pk1=1; 32 | 33 | select 34 | rec, 35 | is_rls_enabled, 36 | subscription_ids, 37 | errors 38 | from 39 | walrus; 40 | 41 | -- Option 2: 42 | -- Replica Identity Full: false 43 | -- Row Level Security : true 44 | 45 | -- Expect: 46 | -- old_record contains only primary key info because only pkey info available in WAL 47 | alter table public.notes replica identity default; 48 | alter table public.notes enable row level security; 49 | insert into public.notes(pk1, body) values (1, 'take out trash'); 50 | select clear_wal(); 51 | delete from public.notes where pk1=1; 52 | 53 | select 54 | rec, 55 | is_rls_enabled, 56 | subscription_ids, 57 | errors 58 | from 59 | walrus; 60 | 61 | 62 | -- Option 3: 63 | -- Replica Identity Full: true 64 | -- Row Level Security : false 65 | 66 | -- Expect: 67 | -- old_record contains all columns becaues they're all available and there is no RLS so info is public 68 | alter table public.notes replica identity full; 69 | alter table public.notes disable row level security; 70 | 71 | insert into public.notes(pk1, body) values (1, 'take out trash'); 72 | select clear_wal(); 73 | delete from public.notes where pk1=1; 74 | 75 | select 76 | rec, 77 | is_rls_enabled, 78 | subscription_ids, 79 | errors 80 | from 81 | walrus; 82 | 83 | -- Option 4: 84 | -- Replica Identity Full: true 85 | -- Row Level Security : true 86 | 87 | -- Expect: 88 | -- old_record contains only primary key info because we can not enforce RLS on deletes and some columns might be private 89 | alter table public.notes replica identity full; 90 | alter table public.notes enable row level security; 91 | insert into public.notes(pk1, body) values (1, 'take out trash'); 92 | select clear_wal(); 93 | delete from public.notes where pk1=1; 94 | 95 | select 96 | rec, 97 | is_rls_enabled, 98 | subscription_ids, 99 | errors 100 | from 101 | walrus; 102 | 103 | select pg_drop_replication_slot('realtime'); 104 | drop table public.notes; 105 | truncate table realtime.subscription; 106 | -------------------------------------------------------------------------------- /test/sql/test_error_no_primary_key.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | create table public.notes( 8 | id int 9 | ); 10 | 11 | insert into realtime.subscription(subscription_id, entity, claims) 12 | select 13 | seed_uuid(1), 14 | 'public.notes', 15 | jsonb_build_object( 16 | 'role', 'authenticated', 17 | 'email', 'example@example.com', 18 | 'sub', seed_uuid(2)::text 19 | ); 20 | 21 | select clear_wal(); 22 | insert into public.notes(id) values (1); 23 | 24 | select 25 | rec, 26 | is_rls_enabled, 27 | subscription_ids, 28 | errors 29 | from 30 | walrus; 31 | 32 | 33 | drop table public.notes; 34 | select pg_drop_replication_slot('realtime'); 35 | truncate table realtime.subscription; 36 | -------------------------------------------------------------------------------- /test/sql/test_error_payload_too_large.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | create table public.notes( 8 | id int primary key, 9 | body text 10 | ); 11 | 12 | insert into realtime.subscription(subscription_id, entity, claims) 13 | select 14 | seed_uuid(1), 15 | 'public.notes', 16 | jsonb_build_object( 17 | 'role', 'authenticated', 18 | 'email', 'example@example.com', 19 | 'sub', seed_uuid(2)::text 20 | ); 21 | 22 | insert into public.notes(id) values (1); 23 | select clear_wal(); 24 | update public.notes set body = repeat('a', 5 * 1024 * 1024); 25 | 26 | select 27 | rec, 28 | is_rls_enabled, 29 | subscription_ids, 30 | errors 31 | from 32 | walrus; 33 | 34 | 35 | drop table public.notes; 36 | select pg_drop_replication_slot('realtime'); 37 | truncate table realtime.subscription; 38 | -------------------------------------------------------------------------------- /test/sql/test_error_unauthorized.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that an error is thrown when attempting to subscribe to a table the role can not select from 3 | */ 4 | 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | create table public.notes( 8 | id int primary key 9 | ); 10 | 11 | revoke select on public.notes from authenticated; 12 | 13 | insert into realtime.subscription(subscription_id, entity, claims) 14 | select 15 | seed_uuid(1), 16 | 'public.notes', 17 | jsonb_build_object( 18 | 'role', 'authenticated', 19 | 'email', 'example@example.com', 20 | 'sub', seed_uuid(2)::text 21 | ); 22 | 23 | select clear_wal(); 24 | insert into public.notes(id) values (1); 25 | 26 | select 27 | rec, 28 | is_rls_enabled, 29 | subscription_ids, 30 | errors 31 | from 32 | walrus; 33 | 34 | 35 | drop table public.notes; 36 | select pg_drop_replication_slot('realtime'); 37 | truncate table realtime.subscription; 38 | -------------------------------------------------------------------------------- /test/sql/test_integration_filters.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | alter table public.notes replica identity full; 9 | 10 | insert into realtime.subscription(subscription_id, entity, claims, filters) 11 | select 12 | seed_uuid(id), 13 | 'public.notes', 14 | jsonb_build_object( 15 | 'role', 'authenticated', 16 | 'email', 'example@example.com', 17 | 'sub', seed_uuid(id)::text 18 | ), 19 | array[(column_name, op, value)::realtime.user_defined_filter] 20 | from 21 | ( 22 | values 23 | (1 , 'body', 'eq', 'bbb'), 24 | (2 , 'body', 'eq', 'aaaa'), 25 | (3 , 'body', 'eq', 'cc') 26 | 27 | ) f(id, column_name, op, value); 28 | 29 | 30 | select clear_wal(); 31 | insert into public.notes(id, body) values (1, 'bbb'); 32 | 33 | delete from public.notes; 34 | 35 | select subscription_id, filters from realtime.subscription; 36 | 37 | select 38 | rec, 39 | is_rls_enabled, 40 | subscription_ids, 41 | errors 42 | from 43 | walrus; 44 | 45 | 46 | drop table public.notes; 47 | select pg_drop_replication_slot('realtime'); 48 | truncate table realtime.subscription; 49 | -------------------------------------------------------------------------------- /test/sql/test_integration_in_filter.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | alter table public.notes replica identity full; 9 | 10 | insert into realtime.subscription(subscription_id, entity, claims, filters) 11 | select 12 | seed_uuid(id), 13 | 'public.notes', 14 | jsonb_build_object( 15 | 'role', 'authenticated', 16 | 'email', 'example@example.com', 17 | 'sub', seed_uuid(id)::text 18 | ), 19 | array[(column_name, op, value)::realtime.user_defined_filter] 20 | from 21 | ( 22 | values 23 | (1 , 'body', 'in', array['aaa', 'bbb', 'ccc']::text), 24 | (2 , 'body', 'in', array['aaa', 'ccc']::text), 25 | (3 , 'body', 'in', array[]::text[]::text) 26 | 27 | ) f(id, column_name, op, value); 28 | 29 | 30 | select clear_wal(); 31 | insert into public.notes(id, body) values (1, 'bbb'); 32 | 33 | delete from public.notes; 34 | 35 | select subscription_id, filters from realtime.subscription; 36 | 37 | select 38 | rec, 39 | is_rls_enabled, 40 | subscription_ids, 41 | errors 42 | from 43 | walrus; 44 | 45 | -- Confirm that filtering on `in` more than 100 entries throws an error 46 | insert into realtime.subscription(subscription_id, entity, claims, filters) 47 | select 48 | seed_uuid(6), 49 | 'public.notes', 50 | jsonb_build_object( 51 | 'role', 'authenticated', 52 | 'email', 'example@example.com', 53 | 'sub', seed_uuid(6)::text 54 | ), 55 | array[('body', 'in', array[1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1])::realtime.user_defined_filter]; 56 | 57 | drop table public.notes; 58 | select pg_drop_replication_slot('realtime'); 59 | truncate table realtime.subscription; 60 | -------------------------------------------------------------------------------- /test/sql/test_integration_in_uuid_filter.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | identifier uuid 6 | ); 7 | 8 | alter table public.notes replica identity full; 9 | 10 | insert into realtime.subscription(subscription_id, entity, claims, filters) 11 | select 12 | seed_uuid(5), 13 | 'public.notes', 14 | jsonb_build_object( 15 | 'role', 'authenticated', 16 | 'email', 'example@example.com', 17 | 'sub', seed_uuid(6)::text 18 | ), 19 | array[( 20 | 'identifier', 21 | 'in', 22 | '{ace23052-568e-4951-acc8-fd510ec667f9,7057e8c3-c05f-4944-b9d9-05f8c45393d1}' 23 | )::realtime.user_defined_filter]; 24 | 25 | 26 | select clear_wal(); 27 | insert into public.notes(id, identifier) values (1, 'ace23052-568e-4951-acc8-fd510ec667f9'); 28 | delete from public.notes; 29 | 30 | select subscription_id, filters from realtime.subscription; 31 | 32 | select 33 | rec, 34 | is_rls_enabled, 35 | subscription_ids, 36 | errors 37 | from 38 | walrus; 39 | 40 | drop table public.notes; 41 | select pg_drop_replication_slot('realtime'); 42 | truncate table realtime.subscription; 43 | -------------------------------------------------------------------------------- /test/sql/test_non_public_schema.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create schema dev; 4 | 5 | create table dev.notes( 6 | id int primary key 7 | ); 8 | 9 | grant usage on schema dev to authenticated; 10 | grant select on dev.notes to authenticated; 11 | 12 | insert into realtime.subscription(subscription_id, entity, claims) 13 | select 14 | seed_uuid(1), 15 | 'dev.notes', 16 | jsonb_build_object( 17 | 'role', 'authenticated', 18 | 'email', 'example@example.com', 19 | 'sub', seed_uuid(1)::text 20 | ); 21 | 22 | select clear_wal(); 23 | insert into dev.notes(id) values (1); 24 | 25 | select 26 | rec, 27 | is_rls_enabled, 28 | subscription_ids, 29 | errors 30 | from 31 | walrus; 32 | 33 | 34 | drop table dev.notes; 35 | select pg_drop_replication_slot('realtime'); 36 | truncate table realtime.subscription; 37 | -------------------------------------------------------------------------------- /test/sql/test_old_record_is_primary_key.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Test that the "old_record" key for updates (and deletes) contains primary key info 3 | 4 | */ 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | create table public.notes( 8 | pk1 int, 9 | pk2 char, 10 | body text, 11 | primary key (pk1, pk2) 12 | ); 13 | 14 | 15 | insert into realtime.subscription(subscription_id, entity, claims) 16 | select 17 | seed_uuid(1), 18 | 'public.notes', 19 | jsonb_build_object( 20 | 'role', 'authenticated', 21 | 'email', 'example@example.com', 22 | 'sub', seed_uuid(1)::text 23 | ); 24 | 25 | insert into public.notes(pk1, pk2, body) values (1, 'a', 'take out trash'); 26 | select clear_wal(); 27 | update public.notes set pk1 =1; 28 | 29 | select 30 | rec, 31 | is_rls_enabled, 32 | subscription_ids, 33 | errors 34 | from 35 | walrus; 36 | 37 | 38 | drop table public.notes; 39 | select pg_drop_replication_slot('realtime'); 40 | truncate table realtime.subscription; 41 | -------------------------------------------------------------------------------- /test/sql/test_old_record_replica_identity_full.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Test that the "old_record" key for updates (and deletes) contains all columns 3 | when the replica identity is full 4 | 5 | */ 6 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 7 | 8 | create table public.notes( 9 | pk1 int, 10 | pk2 char, 11 | body text, 12 | primary key (pk1, pk2) 13 | ); 14 | 15 | alter table public.notes replica identity full; 16 | 17 | insert into realtime.subscription(subscription_id, entity, claims) 18 | select 19 | seed_uuid(1), 20 | 'public.notes', 21 | jsonb_build_object( 22 | 'role', 'authenticated', 23 | 'email', 'example@example.com', 24 | 'sub', seed_uuid(1)::text 25 | ); 26 | 27 | insert into public.notes(pk1, pk2, body) values (1, 'a', 'take out trash'); 28 | select clear_wal(); 29 | update public.notes set pk1 =1; 30 | 31 | select 32 | rec, 33 | is_rls_enabled, 34 | subscription_ids, 35 | errors 36 | from 37 | walrus; 38 | 39 | 40 | drop table public.notes; 41 | select pg_drop_replication_slot('realtime'); 42 | truncate table realtime.subscription; 43 | -------------------------------------------------------------------------------- /test/sql/test_query_from_publication.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Test that only tables in the publication are selected by the polling_query view 3 | */ 4 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 5 | 6 | create table public.notes( 7 | id int primary key, 8 | user_id uuid 9 | ); 10 | 11 | create table public.not_in_pub( 12 | id int primary key 13 | ); 14 | 15 | drop publication supabase_realtime; 16 | 17 | create publication 18 | supabase_realtime 19 | for table 20 | public.notes 21 | with ( 22 | publish = 'insert,update,delete' 23 | ); 24 | 25 | 26 | insert into realtime.subscription(subscription_id, entity, claims) 27 | select 28 | seed_uuid(1), 29 | 'public.notes', 30 | jsonb_build_object( 31 | 'role', 'authenticated', 32 | 'email', 'example@example.com', 33 | 'sub', seed_uuid(1)::text 34 | ); 35 | 36 | insert into realtime.subscription(subscription_id, entity, claims) 37 | select 38 | seed_uuid(1), 39 | 'public.not_in_pub', 40 | jsonb_build_object( 41 | 'role', 'authenticated', 42 | 'email', 'example@example.com', 43 | 'sub', seed_uuid(1)::text 44 | ); 45 | 46 | 47 | 48 | select clear_wal(); 49 | insert into public.notes(id) values (1); 50 | insert into public.not_in_pub(id) values (1); 51 | 52 | select pubname, schemaname, tablename, attnames from pg_publication_tables; 53 | 54 | 55 | select 56 | jsonb_pretty(wal - 'commit_timestamp'), 57 | is_rls_enabled, 58 | subscription_ids, 59 | errors 60 | from 61 | polling_query; 62 | 63 | 64 | drop table public.not_in_pub; 65 | drop table public.notes; 66 | truncate table realtime.subscription; 67 | drop publication supabase_realtime; 68 | -------------------------------------------------------------------------------- /test/sql/test_rls_skips_subscriber.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that subscriber is omitted when record not visible to them in the RLS policy 3 | */ 4 | 5 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 6 | 7 | create table public.notes( 8 | id int primary key, 9 | user_id uuid 10 | ); 11 | 12 | create policy rls_note_select 13 | on public.notes 14 | to authenticated 15 | using (user_id = auth.uid()); 16 | 17 | alter table public.notes enable row level security; 18 | 19 | insert into realtime.subscription(subscription_id, entity, claims) 20 | select 21 | seed_uuid(1), -- matches for convienence, not required, 22 | 'public.notes', 23 | jsonb_build_object( 24 | 'role', 'authenticated', 25 | 'email', 'example@example.com', 26 | 'sub', seed_uuid(1)::text -- should see result according to RLS 27 | ); 28 | 29 | insert into realtime.subscription(subscription_id, entity, claims) 30 | select 31 | seed_uuid(2), -- matches for convienence, not required, 32 | 'public.notes', 33 | jsonb_build_object( 34 | 'role', 'authenticated', 35 | 'email', 'example@example.com', 36 | 'sub', seed_uuid(2)::text -- should NOT see result 37 | ); 38 | 39 | 40 | select clear_wal(); 41 | insert into public.notes(id, user_id) values (1, seed_uuid(1)); 42 | 43 | begin; 44 | select 45 | -- set an auth.uid() to seed_uuid(1) 46 | set_config( 47 | 'request.jwt.claims', 48 | jsonb_build_object( 49 | 'role', 'authenticated', 50 | 'email', 'example@example.com', 51 | 'sub', seed_uuid(1)::text 52 | )::text, 53 | true 54 | ); 55 | 56 | select auth.uid(); 57 | 58 | -- Expect 1 entry in the subscriber array matching ^ 59 | select 60 | rec, 61 | is_rls_enabled, 62 | subscription_ids, 63 | errors 64 | from 65 | walrus; 66 | 67 | end; 68 | 69 | drop table public.notes; 70 | select pg_drop_replication_slot('realtime'); 71 | truncate table realtime.subscription; 72 | -------------------------------------------------------------------------------- /test/sql/test_role_with_hyphen.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | 4 | create role "has-hyphen" nologin noinherit; 5 | 6 | create schema private; 7 | 8 | grant usage on schema private to "has-hyphen"; 9 | alter default privileges in schema private grant all on tables to "has-hyphen"; 10 | alter default privileges in schema private grant all on functions to "has-hyphen"; 11 | alter default privileges in schema private grant all on sequences to "has-hyphen"; 12 | 13 | create table private.notes( 14 | id int primary key 15 | ); 16 | 17 | create policy rls_note_select 18 | on private.notes 19 | to "has-hyphen" 20 | using (true); 21 | 22 | alter table private.notes enable row level security; 23 | 24 | insert into realtime.subscription(subscription_id, entity, claims) 25 | select 26 | seed_uuid(1), 27 | 'private.notes', 28 | jsonb_build_object( 29 | 'role', 'has-hyphen', 30 | 'email', 'example@example.com', 31 | 'sub', seed_uuid(1)::text 32 | ); 33 | 34 | select clear_wal(); 35 | insert into private.notes(id) values (1); 36 | 37 | select 38 | rec, 39 | is_rls_enabled, 40 | subscription_ids, 41 | errors 42 | from 43 | walrus; 44 | 45 | 46 | drop table private.notes; 47 | drop schema private; 48 | select pg_drop_replication_slot('realtime'); 49 | truncate table realtime.subscription; 50 | -------------------------------------------------------------------------------- /test/sql/test_select_one.sql: -------------------------------------------------------------------------------- 1 | select 1; 2 | -------------------------------------------------------------------------------- /test/sql/test_simple_delete.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | insert into realtime.subscription(subscription_id, entity, claims) 9 | select 10 | seed_uuid(1), 11 | 'public.notes', 12 | jsonb_build_object( 13 | 'role', 'authenticated', 14 | 'email', 'example@example.com', 15 | 'sub', seed_uuid(1)::text 16 | ); 17 | 18 | insert into public.notes(id, body) values (1, 'take out trash'); 19 | select clear_wal(); 20 | delete from public.notes; 21 | 22 | select 23 | rec, 24 | is_rls_enabled, 25 | subscription_ids, 26 | errors 27 | from 28 | walrus; 29 | 30 | 31 | drop table public.notes; 32 | select pg_drop_replication_slot('realtime'); 33 | truncate table realtime.subscription; 34 | -------------------------------------------------------------------------------- /test/sql/test_simple_insert.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key 5 | ); 6 | 7 | insert into realtime.subscription(subscription_id, entity, claims) 8 | select 9 | seed_uuid(1), 10 | 'public.notes', 11 | jsonb_build_object( 12 | 'role', 'authenticated', 13 | 'email', 'example@example.com', 14 | 'sub', seed_uuid(1)::text 15 | ); 16 | 17 | select clear_wal(); 18 | insert into public.notes(id) values (1); 19 | 20 | select 21 | rec, 22 | is_rls_enabled, 23 | subscription_ids, 24 | errors 25 | from 26 | walrus; 27 | 28 | 29 | drop table public.notes; 30 | select pg_drop_replication_slot('realtime'); 31 | truncate table realtime.subscription; 32 | -------------------------------------------------------------------------------- /test/sql/test_simple_update.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | insert into realtime.subscription(subscription_id, entity, claims) 9 | select 10 | seed_uuid(1), 11 | 'public.notes', 12 | jsonb_build_object( 13 | 'role', 'authenticated', 14 | 'email', 'example@example.com', 15 | 'sub', seed_uuid(1)::text 16 | ); 17 | 18 | insert into public.notes(id, body) values (1, 'take out trash'); 19 | select clear_wal(); 20 | update public.notes set id=2; 21 | 22 | select 23 | rec, 24 | is_rls_enabled, 25 | subscription_ids, 26 | errors 27 | from 28 | walrus; 29 | 30 | 31 | drop table public.notes; 32 | select pg_drop_replication_slot('realtime'); 33 | truncate table realtime.subscription; 34 | -------------------------------------------------------------------------------- /test/sql/test_subscribers_multiple_roles.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Tests that when multiple roles are subscribed to the same table, a WAL record 3 | is split into 2 rows so permissions can be handled independently 4 | 5 | The authenticated role has limited access to `public.notes` and has one field 6 | redacted in the output. 7 | */ 8 | 9 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 10 | 11 | create table public.notes( 12 | id int primary key, 13 | body text 14 | ); 15 | 16 | revoke select on public.notes from authenticated; 17 | grant select (id) on public.notes to authenticated; 18 | 19 | 20 | insert into realtime.subscription(subscription_id, entity, claims) 21 | select 22 | seed_uuid(a.ix::int), 23 | 'public.notes', 24 | jsonb_build_object( 25 | 'role', role_name, 26 | 'email', 'example@example.com', 27 | 'sub', seed_uuid(3)::text 28 | ) 29 | from 30 | unnest( 31 | array['authenticated', 'postgres'] 32 | ) with ordinality a(role_name, ix); 33 | 34 | 35 | insert into public.notes(id, body) values (1, 'hello'); 36 | 37 | select 38 | rec, 39 | is_rls_enabled, 40 | subscription_ids, 41 | errors 42 | from 43 | walrus; 44 | 45 | 46 | drop table public.notes; 47 | select pg_drop_replication_slot('realtime'); 48 | truncate table realtime.subscription; 49 | -------------------------------------------------------------------------------- /test/sql/test_unchanged_toast.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body1 text, 6 | body2 text 7 | ); 8 | alter table public.notes replica identity full; 9 | 10 | -- Disable compression to force values to be TOASTed 11 | alter table public.notes alter column body2 set storage external; 12 | alter table public.notes alter column body1 set storage external; 13 | 14 | insert into realtime.subscription(subscription_id, entity, claims) 15 | select 16 | seed_uuid(1), 17 | 'public.notes', 18 | jsonb_build_object( 19 | 'role', 'authenticated', 20 | 'email', 'example@example.com', 21 | 'sub', seed_uuid(2)::text 22 | ); 23 | 24 | insert into public.notes(id, body1, body2) 25 | values (1, repeat('1', 2 * 1024), repeat('2', 2 * 1024)); 26 | select clear_wal(); 27 | 28 | update public.notes set body1 = 'new'; 29 | 30 | select 31 | rec, 32 | is_rls_enabled, 33 | subscription_ids, 34 | errors 35 | from 36 | walrus; 37 | 38 | 39 | drop table public.notes; 40 | select pg_drop_replication_slot('realtime'); 41 | truncate table realtime.subscription; 42 | -------------------------------------------------------------------------------- /test/sql/test_unit_filters.sql: -------------------------------------------------------------------------------- 1 | select realtime.check_equality_op('eq', 'text', 'aaa', 'aaa'); 2 | select realtime.check_equality_op('eq', 'text', 'aaa', 'bbb'); 3 | select realtime.check_equality_op('neq', 'text', 'aaa', 'aaa'); 4 | select realtime.check_equality_op('neq', 'text', 'aaa', 'bbb'); 5 | select realtime.check_equality_op('lt', 'text', 'aaa', 'bbb'); 6 | select realtime.check_equality_op('lt', 'text', 'bbb', 'aaa'); 7 | select realtime.check_equality_op('lt', 'text', 'bbb', 'bbb'); 8 | select realtime.check_equality_op('lte', 'text', 'aaa', 'bbb'); 9 | select realtime.check_equality_op('lte', 'text', 'bbb', 'aaa'); 10 | select realtime.check_equality_op('lte', 'text', 'bbb', 'bbb'); 11 | select realtime.check_equality_op('gt', 'text', 'aaa', 'bbb'); 12 | select realtime.check_equality_op('gt', 'text', 'bbb', 'aaa'); 13 | select realtime.check_equality_op('gt', 'text', 'bbb', 'bbb'); 14 | select realtime.check_equality_op('gte', 'text', 'aaa', 'bbb'); 15 | select realtime.check_equality_op('gte', 'text', 'bbb', 'aaa'); 16 | select realtime.check_equality_op('gte', 'text', 'bbb', 'bbb'); 17 | select realtime.check_equality_op('eq', 'bigint', '1', '1'); 18 | select realtime.check_equality_op('eq', 'bigint', '2', '1'); 19 | select realtime.check_equality_op('eq', 'bigint', '2', null); 20 | 21 | select realtime.check_equality_op('eq','uuid','639f86b1-738b-43ed-bb09-c8d3f3bafa30','639f86b1-738b-43ed-bb09-c8d3f3bafa30'); 22 | select realtime.check_equality_op('eq','uuid','639f86b1-738b-43ed-bb09-c8d3f3bafa30','b423f213-ac24-402a-95ea-cf1d94d8e9f0'); 23 | 24 | select realtime.check_equality_op('in', 'bigint', '2', '{1,2,3}'); 25 | select realtime.check_equality_op('in', 'bigint', '4', '{1,2,3}'); 26 | -------------------------------------------------------------------------------- /test/sql/test_wal2json_output.sql: -------------------------------------------------------------------------------- 1 | select 1 from pg_create_logical_replication_slot('realtime', 'wal2json', false); 2 | 3 | create table public.notes( 4 | id int primary key, 5 | body text 6 | ); 7 | 8 | begin; 9 | insert into public.notes(id, body) values (1, 'hello'); 10 | update public.notes set body = 'world'; 11 | delete from public.notes; 12 | end; 13 | 14 | select 15 | jsonb_pretty(norm(x.data::jsonb)) 16 | from 17 | pg_logical_slot_get_changes( 18 | 'realtime', null, null, 19 | 'include-pk', '1', 20 | 'include-transaction', 'false', 21 | 'include-timestamp', 'true', 22 | 'include-type-oids', 'true', 23 | 'format-version', '2', 24 | 'actions', 'insert,update,delete', 25 | 'add-tables', 'public.notes' 26 | ) x; 27 | 28 | select pg_drop_replication_slot('realtime'); 29 | drop table public.notes; 30 | truncate table realtime.subscription; 31 | --------------------------------------------------------------------------------