├── .clang-format ├── .gitignore ├── .rubocop.yml ├── LICENSE ├── Makefile ├── NEWS ├── README.md ├── safeupdate.c └── test.rb /.clang-format: -------------------------------------------------------------------------------- 1 | --- 2 | Language: Cpp 3 | AlwaysBreakAfterReturnType: AllDefinitions 4 | BinPackArguments: false 5 | BraceWrapping: 6 | AfterControlStatement: true 7 | AfterFunction: true 8 | BreakBeforeBraces: Custom 9 | IndentCaseLabels: true 10 | IndentWidth: 4 11 | SpaceAfterCStyleCast: true 12 | SpaceAfterTemplateKeyword: false 13 | TabWidth: 4 14 | UseTab: Always 15 | ... 16 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.so 2 | *.o 3 | -------------------------------------------------------------------------------- /.rubocop.yml: -------------------------------------------------------------------------------- 1 | AllCops: 2 | NewCops: enable 3 | 4 | Style/HashSyntax: 5 | EnforcedStyle: no_mixed_keys 6 | 7 | Metrics/MethodLength: 8 | Max: 20 9 | 10 | Style/FrozenStringLiteralComment: 11 | Enabled: false 12 | 13 | Style/FetchEnvVar: 14 | Enabled: false 15 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Source code for `pg-safeupdate` is licensed under an ISC-style license, to the 2 | following copyright holders: 3 | 4 | Eric Radman 5 | 6 | * Permission to use, copy, modify, and distribute this software for any 7 | * purpose with or without fee is hereby granted, provided that the above 8 | * copyright notice and this permission notice appear in all copies. 9 | * 10 | * THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES 11 | * WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF 12 | * MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR 13 | * ANY SPECIAL, DIRECT, INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES 14 | * WHATSOEVER RESULTING FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN 15 | * ACTION OF CONTRACT, NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF 16 | * OR IN CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. 17 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | RUBOCOP ?= rubocop 2 | CLANG_FORMAT ?= clang-format 3 | RELEASE = 1.5 4 | MODULES = safeupdate 5 | PG_CONFIG = pg_config 6 | PGXS := $(shell $(PG_CONFIG) --pgxs) 7 | RUBY = ruby 8 | include $(PGXS) 9 | 10 | test: ${MODULES}.so 11 | @${RUBY} ./test.rb 12 | 13 | distclean: 14 | rm -f trace.out 15 | 16 | format: 17 | ${RUBOCOP} -A 18 | ${CLANG_FORMAT} -i *.c 19 | 20 | .PHONY: distclean format test 21 | -------------------------------------------------------------------------------- /NEWS: -------------------------------------------------------------------------------- 1 | = Release History 2 | 3 | == 1.5: November 14, 2023 4 | 5 | - Require PostgreSQL >= 14 6 | - Use ${RUBY} instead of `ruby' for tests 7 | 8 | == 1.4: June 3, 2021 9 | 10 | - Correct invocation of 'errmsg()' 11 | - Adapt build for PostgreSQL 14 12 | 13 | == 1.3: September 25, 2019 14 | 15 | - Move hosting from bitbucket.org to github.com 16 | - Rename tag names from pg-safeupdate-X.Y to X.Y 17 | 18 | == 1.2: June 11, 2019 19 | 20 | - GUC for disabling the extension using 'SET safeupdate.enable=0' 21 | 22 | == 1.1: July 24, 2017 23 | 24 | - Evaluate common table expressions (CTE) that attempt to modify data 25 | 26 | == 1.0: July 28, 2016 27 | 28 | - Initial concept https://bitbucket.org/eradman/safeupdate 29 | - safeupdate, a extension to require a WHERE clause for UPDATE and DELETE 30 | - Use jointree instead of matching on substrings (based on delete_needs_where.c 31 | by Robert Haas) 32 | 33 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Require SQL Where Clause 2 | ======================== 3 | 4 | `safeupdate` is a simple extension to PostgreSQL that raises an error if 5 | `UPDATE` and `DELETE` are executed without specifying conditions. This 6 | extension was initially designed to protect data from accidental obliteration of 7 | data that is writable by [PostgREST]. 8 | 9 | Installation 10 | ------------ 11 | 12 | Build from source using 13 | 14 | gmake 15 | gmake install 16 | 17 | Activate per-session by running 18 | 19 | load 'safeupdate'; 20 | 21 | Make this mandatory for all databases and connections by adding the following to 22 | `postgresql.conf`: 23 | 24 | shared_preload_libraries=safeupdate 25 | 26 | Or enable for a specific database using 27 | 28 | ALTER DATABASE mydb SET session_preload_libraries = 'safeupdate'; 29 | 30 | Options 31 | ------- 32 | 33 | Once loaded this extension can be administratively disabled by setting 34 | 35 | SET safeupdate.enabled=0; 36 | 37 | Examples 38 | -------- 39 | 40 | Try to update records without `WHERE` clause 41 | 42 | UPDATE FROM rack SET fan_speed=70; 43 | -- ERROR: UPDATE requires a WHERE clause 44 | 45 | Select results from a CTE that attempts to modify data: 46 | 47 | WITH updates AS ( 48 | UPDATE rack SET fan_speed=70 49 | RETURNING * 50 | ) 51 | SELECT * FROM updates; 52 | -- ERROR: UPDATE requires a WHERE clause 53 | 54 | Set a column value for a range of records 55 | 56 | UPDATE rack SET fan_speed=90 WHERE fan_speed=70; 57 | 58 | Set a column value for all the records in a table 59 | 60 | UPDATE rack SET fan_speed=90 WHERE 1=1; 61 | 62 | News 63 | ---- 64 | 65 | Notification of new releases are provided by an 66 | [Atom feed](https://github.com/eradman/pg-safeupdate/releases.atom), 67 | and release history is covered in the [NEWS](NEWS) file. 68 | 69 | [PostgREST]: http://postgrest.com 70 | -------------------------------------------------------------------------------- /safeupdate.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | 3 | #include "fmgr.h" 4 | #include "nodes/nodeFuncs.h" 5 | #include "parser/analyze.h" 6 | #include "utils/guc.h" 7 | 8 | PG_MODULE_MAGIC; 9 | 10 | void _PG_init(void); 11 | static bool safeupdate_enabled; 12 | static post_parse_analyze_hook_type prev_post_parse_analyze_hook = NULL; 13 | 14 | static void 15 | delete_needs_where_check(ParseState *pstate, Query *query, JumbleState *jstate) 16 | { 17 | ListCell *l; 18 | Query *ctequery; 19 | 20 | if (!safeupdate_enabled) 21 | return; 22 | 23 | if (query->hasModifyingCTE) 24 | { 25 | foreach (l, query->cteList) 26 | { 27 | CommonTableExpr *cte = (CommonTableExpr *) lfirst(l); 28 | ctequery = castNode(Query, cte->ctequery); 29 | delete_needs_where_check(pstate, ctequery, jstate); 30 | } 31 | } 32 | 33 | switch (query->commandType) 34 | { 35 | case CMD_DELETE: 36 | Assert(query->jointree != NULL); 37 | if (query->jointree->quals == NULL) 38 | ereport(ERROR, 39 | (errcode(ERRCODE_CARDINALITY_VIOLATION), 40 | errmsg("DELETE requires a WHERE clause"))); 41 | break; 42 | case CMD_UPDATE: 43 | Assert(query->jointree != NULL); 44 | if (query->jointree->quals == NULL) 45 | ereport(ERROR, 46 | (errcode(ERRCODE_CARDINALITY_VIOLATION), 47 | errmsg("UPDATE requires a WHERE clause"))); 48 | default: 49 | break; 50 | } 51 | if (prev_post_parse_analyze_hook != NULL) 52 | (*prev_post_parse_analyze_hook)(pstate, query, jstate); 53 | } 54 | 55 | void 56 | _PG_init(void) 57 | { 58 | DefineCustomBoolVariable("safeupdate.enabled", 59 | "Enforce qualified updates", 60 | "Prevent DML without a WHERE clause", 61 | &safeupdate_enabled, 62 | 1, 63 | PGC_SUSET, 64 | 0, 65 | NULL, 66 | NULL, 67 | NULL); 68 | prev_post_parse_analyze_hook = post_parse_analyze_hook; 69 | post_parse_analyze_hook = delete_needs_where_check; 70 | } 71 | -------------------------------------------------------------------------------- /test.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | require 'open3' 4 | 5 | # Test Utilities 6 | @tests = 0 7 | @test_description = 0 8 | 9 | def try(descr) 10 | start = Time.now 11 | @tests += 1 12 | @test_description = descr 13 | yield 14 | delta = format('%.3f', (Time.now - start)) 15 | # highlight slow tests 16 | delta = "\e[7m#{delta}\e[27m" if (Time.now - start) > 0.03 17 | puts "#{delta}: #{descr}" 18 | end 19 | 20 | def eq(result, expected) 21 | a = result.to_s.gsub(/^/, '> ') 22 | b = expected.to_s.gsub(/^/, '< ') 23 | raise "\"#{@test_description}\"\n#{a}\n#{b}" unless result == expected 24 | end 25 | 26 | # Setup 27 | @url = `pg_tmp -o "-c shared_preload_libraries=#{Dir.pwd}/safeupdate"` 28 | psql = "psql --no-psqlrc -At -q #{@url}" 29 | puts "using #{@url}" 30 | q = %{ 31 | CREATE TABLE employees (name varchar(30)); 32 | INSERT INTO employees VALUES ('Eric'),('kevin'),('Robert'); 33 | } 34 | out, err, status = Open3.capture3(psql, :stdin_data => q) 35 | eq err, '' 36 | eq out, '' 37 | eq status.success?, true 38 | 39 | # Tests 40 | 41 | try 'Block unqualified DELETE' do 42 | q = %( 43 | DELETE FROM employees; 44 | ) 45 | out, err, status = Open3.capture3(psql, :stdin_data => q) 46 | eq err, "ERROR: DELETE requires a WHERE clause\n" 47 | eq status.success?, true 48 | eq out, '' 49 | end 50 | 51 | try 'Block unqualified UPDATE' do 52 | q = %( 53 | UPDATE employees SET name='Kevin'; 54 | ) 55 | out, err, status = Open3.capture3(psql, :stdin_data => q) 56 | eq err, "ERROR: UPDATE requires a WHERE clause\n" 57 | eq out, '' 58 | eq status.success?, true 59 | end 60 | 61 | try 'Allow qualified DELETE' do 62 | q = %( 63 | BEGIN; 64 | DELETE FROM employees WHERE name='Robert' RETURNING name; 65 | ROLLBACK; 66 | ) 67 | out, err, status = Open3.capture3(psql, :stdin_data => q) 68 | eq err.empty?, true 69 | eq out, "Robert\n" 70 | eq status.success?, true 71 | end 72 | 73 | try 'Allow qualified UPDATE' do 74 | q = %( 75 | BEGIN; 76 | UPDATE employees SET name='Kevin' 77 | WHERE name='kevin' 78 | RETURNING name; 79 | ROLLBACK; 80 | ) 81 | out, err, status = Open3.capture3(psql, :stdin_data => q) 82 | eq err, '' 83 | eq out, "Kevin\n" 84 | eq status.success?, true 85 | end 86 | 87 | try 'Block modifying CTE with unqualified UPDATE' do 88 | q = %{ 89 | WITH updates AS ( 90 | UPDATE employees SET name='Kevin' 91 | RETURNING name 92 | ) 93 | SELECT * 94 | FROM updates; 95 | } 96 | out, err, status = Open3.capture3(psql, :stdin_data => q) 97 | eq err, "ERROR: UPDATE requires a WHERE clause\n" 98 | eq out, '' 99 | eq status.success?, true 100 | end 101 | 102 | try 'Allow modifying CTE with qualified UPDATE' do 103 | q = %{ 104 | BEGIN; 105 | WITH updates AS ( 106 | UPDATE employees SET name='Kevin' 107 | WHERE name='kevin' 108 | RETURNING name 109 | ) 110 | SELECT * 111 | FROM updates; 112 | ROLLBACK; 113 | } 114 | out, err, status = Open3.capture3(psql, :stdin_data => q) 115 | eq err, '' 116 | eq out, "Kevin\n" 117 | eq status.success?, true 118 | end 119 | 120 | try 'Disable safeupdate' do 121 | q = %( 122 | SHOW safeupdate.enabled; 123 | SET safeupdate.enabled=0; 124 | BEGIN; 125 | DELETE FROM employees; 126 | ROLLBACK; 127 | SET safeupdate.enabled=1; 128 | ) 129 | out, err, status = Open3.capture3(psql, :stdin_data => q) 130 | eq err, '' 131 | eq out, "on\n" 132 | eq status.success?, true 133 | end 134 | 135 | puts "\n#{@tests} tests PASSED" 136 | --------------------------------------------------------------------------------