From dcf4646e2f51b53357b2bb614157e24f6a6ab547 Mon Sep 17 00:00:00 2001 From: Kayssar Daher Date: Tue, 7 Sep 2021 19:22:43 +0200 Subject: [PATCH] feat: Added column level permission grant --- postgresql/helpers.go | 12 ++ postgresql/resource_postgresql_grant.go | 121 ++++++++++++- postgresql/resource_postgresql_grant_test.go | 165 ++++++++++++++++++ postgresql/utils_test.go | 34 +++- website/docs/r/postgresql_grant.html.markdown | 18 +- 5 files changed, 339 insertions(+), 11 deletions(-) diff --git a/postgresql/helpers.go b/postgresql/helpers.go index 1e2e9faf..a99a831c 100644 --- a/postgresql/helpers.go +++ b/postgresql/helpers.go @@ -243,6 +243,7 @@ var allowedPrivileges = map[string][]string{ "type": []string{"ALL", "USAGE"}, "foreign_data_wrapper": []string{"ALL", "USAGE"}, "foreign_server": []string{"ALL", "USAGE"}, + "column": []string{"ALL", "SELECT", "INSERT", "UPDATE", "REFERENCES"}, } // validatePrivileges checks that privileges to apply are allowed for this object type. @@ -282,6 +283,17 @@ func setToPgIdentList(schema string, idents *schema.Set) string { return strings.Join(quotedIdents, ",") } +func setToPgIdentSimpleList(idents *schema.Set) string { + quotedIdents := make([]string, idents.Len()) + for i, ident := range idents.List() { + quotedIdents[i] = fmt.Sprintf( + "%s", + ident.(string), + ) + } + return strings.Join(quotedIdents, ",") +} + // startTransaction starts a new DB transaction on the specified database. // If the database is specified and different from the one configured in the provider, // it will create a new connection pool if needed. diff --git a/postgresql/resource_postgresql_grant.go b/postgresql/resource_postgresql_grant.go index 605ba48f..f83a40d8 100644 --- a/postgresql/resource_postgresql_grant.go +++ b/postgresql/resource_postgresql_grant.go @@ -21,6 +21,7 @@ var allowedObjectTypes = []string{ "table", "foreign_data_wrapper", "foreign_server", + "column", } var objectTypes = map[string]string{ @@ -33,8 +34,9 @@ var objectTypes = map[string]string{ func resourcePostgreSQLGrant() *schema.Resource { return &schema.Resource{ Create: PGResourceFunc(resourcePostgreSQLGrantCreate), - // As create revokes and grants we can use it to update too - Update: PGResourceFunc(resourcePostgreSQLGrantCreate), + // Since all of this resource's arguments force a recreation + // there's no need for an Update function + //Update: Read: PGResourceFunc(resourcePostgreSQLGrantRead), Delete: PGResourceFunc(resourcePostgreSQLGrantDelete), @@ -72,9 +74,18 @@ func resourcePostgreSQLGrant() *schema.Resource { Set: schema.HashString, Description: "The specific objects to grant privileges on for this role (empty means all objects of the requested type)", }, + "columns": { + Type: schema.TypeSet, + Optional: true, + ForceNew: true, + Elem: &schema.Schema{Type: schema.TypeString}, + Set: schema.HashString, + Description: "The specific columns to grant privileges on for this role", + }, "privileges": &schema.Schema{ Type: schema.TypeSet, Required: true, + ForceNew: true, Elem: &schema.Schema{Type: schema.TypeString}, Set: schema.HashString, Description: "The list of privileges to grant", @@ -133,6 +144,18 @@ func resourcePostgreSQLGrantCreate(db *DBConnection, d *schema.ResourceData) err if d.Get("objects").(*schema.Set).Len() > 0 && (objectType == "database" || objectType == "schema") { return fmt.Errorf("cannot specify `objects` when `object_type` is `database` or `schema`") } + if d.Get("columns").(*schema.Set).Len() > 0 && (objectType != "column") { + return fmt.Errorf("cannot specify `columns` when `object_type` is not `column`") + } + if d.Get("columns").(*schema.Set).Len() == 0 && (objectType == "column") { + return fmt.Errorf("must specify `columns` when `object_type` is `column`") + } + if d.Get("privileges").(*schema.Set).Len() != 1 && (objectType == "column") { + return fmt.Errorf("must specify exactly 1 `privileges` when `object_type` is `column`") + } + if (d.Get("objects").(*schema.Set).Len() != 1) && (objectType == "column") { + return fmt.Errorf("must specify exactly 1 table in the `objects` field when `object_type` is `column`") + } if d.Get("objects").(*schema.Set).Len() != 1 && (objectType == "foreign_data_wrapper" || objectType == "foreign_server") { return fmt.Errorf("one element must be specified in `objects` when `object_type` is `foreign_data_wrapper` or `foreign_server`") } @@ -296,6 +319,7 @@ func readRolePrivileges(txn *sql.Tx, d *schema.ResourceData) error { role := d.Get("role").(string) objectType := d.Get("object_type").(string) objects := d.Get("objects").(*schema.Set) + privileges := d.Get("privileges").(*schema.Set) roleOID, err := getRoleOID(txn, role) if err != nil { @@ -338,6 +362,48 @@ GROUP BY pg_proc.proname query, roleOID, d.Get("schema"), ) + case "column": + // The following query is made up of 3 parts + // The first one simply aggregates all privileges on one column in one table into one line. + // The second part fetches all permissions on all columns for a given user & a given table in a give schema. + // The third part fetches all table-level permissions for the aforementioned table. + // Subtracting the third part from the second part allows us + // to get column-level privileges without those created by table-level privileges. + query = ` +SELECT table_name, array_agg(privilege_type) AS column_privileges +FROM ( + SELECT table_name, column_name, privilege_type + FROM information_schema.column_privileges + WHERE + grantee = $1 + AND + table_schema = $2 + AND + table_name = $3 + AND + privilege_type = $6 + EXCEPT + SELECT pg_class.relname, pg_attribute.attname, privilege_type AS table_grant + FROM pg_class + JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace + LEFT JOIN ( + SELECT acls.* + FROM + (SELECT relname, relnamespace, relkind, (aclexplode(relacl)).* FROM pg_class c) as acls + WHERE grantee=$4 + ) privs + USING (relname, relnamespace, relkind) + LEFT JOIN pg_attribute ON pg_class.oid = pg_attribute.attrelid + WHERE nspname = $2 AND relkind = $5 AND attname NOT IN ('ctid', 'cmax', 'cmin', 'tableoid', 'xmin', 'xmax') + ) +AS col_privs_without_table_privs +GROUP BY col_privs_without_table_privs.table_name, col_privs_without_table_privs.column_name +ORDER BY col_privs_without_table_privs.column_name +;` + rows, err = txn.Query( + query, role, d.Get("schema"), objects.List()[0], roleOID, objectTypes["table"], privileges.List()[0], + ) + default: query = ` SELECT pg_class.relname, array_remove(array_agg(privilege_type), NULL) @@ -430,6 +496,19 @@ func createGrantQuery(d *schema.ResourceData, privileges []string) string { pq.QuoteIdentifier(srvName.(string)), pq.QuoteIdentifier(d.Get("role").(string)), ) + case "COLUMN": + objects := d.Get("objects").(*schema.Set) + columns := []string{} + for _, col := range d.Get("columns").(*schema.Set).List() { + columns = append(columns, col.(string)) + } + query = fmt.Sprintf( + "GRANT %s (%s) ON TABLE %s TO %s", + strings.Join(privileges, ","), + strings.Join(columns, ","), + setToPgIdentList(d.Get("schema").(string), objects), + pq.QuoteIdentifier(d.Get("role").(string)), + ) case "TABLE", "SEQUENCE", "FUNCTION": objects := d.Get("objects").(*schema.Set) if objects.Len() > 0 { @@ -488,15 +567,37 @@ func createRevokeQuery(d *schema.ResourceData) string { pq.QuoteIdentifier(srvName.(string)), pq.QuoteIdentifier(d.Get("role").(string)), ) + case "COLUMN": + objects := d.Get("objects").(*schema.Set) + columns := d.Get("columns").(*schema.Set) + privileges := d.Get("privileges").(*schema.Set) + query = fmt.Sprintf( + "REVOKE %s (%s) ON TABLE %s FROM %s", + setToPgIdentSimpleList(privileges), + setToPgIdentSimpleList(columns), + setToPgIdentList(d.Get("schema").(string), objects), + pq.QuoteIdentifier(d.Get("role").(string)), + ) case "TABLE", "SEQUENCE", "FUNCTION": objects := d.Get("objects").(*schema.Set) + privileges := d.Get("privileges").(*schema.Set) if objects.Len() > 0 { - query = fmt.Sprintf( - "REVOKE ALL PRIVILEGES ON %s %s FROM %s", - strings.ToUpper(d.Get("object_type").(string)), - setToPgIdentList(d.Get("schema").(string), objects), - pq.QuoteIdentifier(d.Get("role").(string)), - ) + if privileges.Len() > 0 { + query = fmt.Sprintf( + "REVOKE %s ON %s %s FROM %s", + setToPgIdentSimpleList(privileges), + strings.ToUpper(d.Get("object_type").(string)), + setToPgIdentList(d.Get("schema").(string), objects), + pq.QuoteIdentifier(d.Get("role").(string)), + ) + } else { + query = fmt.Sprintf( + "REVOKE ALL PRIVILEGES ON %s %s FROM %s", + strings.ToUpper(d.Get("object_type").(string)), + setToPgIdentList(d.Get("schema").(string), objects), + pq.QuoteIdentifier(d.Get("role").(string)), + ) + } } else { query = fmt.Sprintf( "REVOKE ALL PRIVILEGES ON ALL %sS IN SCHEMA %s FROM %s", @@ -603,6 +704,10 @@ func generateGrantID(d *schema.ResourceData) string { parts = append(parts, object.(string)) } + for _, column := range d.Get("columns").(*schema.Set).List() { + parts = append(parts, column.(string)) + } + return strings.Join(parts, "_") } diff --git a/postgresql/resource_postgresql_grant_test.go b/postgresql/resource_postgresql_grant_test.go index 682697b9..c266efa4 100644 --- a/postgresql/resource_postgresql_grant_test.go +++ b/postgresql/resource_postgresql_grant_test.go @@ -15,6 +15,7 @@ func TestCreateGrantQuery(t *testing.T) { var databaseName = "foo" var roleName = "bar" var tableObjects = []interface{}{"o1", "o2"} + var tableColumns = []interface{}{"col1", "col2"} var fdwObjects = []interface{}{"baz"} cases := []struct { @@ -97,6 +98,21 @@ func TestCreateGrantQuery(t *testing.T) { privileges: []string{"SELECT"}, expected: fmt.Sprintf(`GRANT SELECT ON TABLE %[1]s."o2",%[1]s."o1" TO %s`, pq.QuoteIdentifier(databaseName), pq.QuoteIdentifier(roleName)), }, + // ********************************* WIP ********************************* + { + resource: schema.TestResourceDataRaw(t, resourcePostgreSQLGrant().Schema, map[string]interface{}{ + "object_type": "column", + "objects": []interface{}{"o1"}, + "columns": tableColumns, + "schema": databaseName, + "role": roleName, + }), + privileges: []string{"SELECT"}, + expected: fmt.Sprintf(`GRANT SELECT (col2,col1) ON TABLE %[1]s."o1" TO %s`, pq.QuoteIdentifier(databaseName), pq.QuoteIdentifier(roleName)), + }, + + // ********************************* END OF WIP ********************************* + { resource: schema.TestResourceDataRaw(t, resourcePostgreSQLGrant().Schema, map[string]interface{}{ "object_type": "foreign_data_wrapper", @@ -149,6 +165,7 @@ func TestCreateRevokeQuery(t *testing.T) { var databaseName = "foo" var roleName = "bar" var tableObjects = []interface{}{"o1", "o2"} + var tableColumns = []interface{}{"col1", "col2"} var fdwObjects = []interface{}{"baz"} cases := []struct { @@ -196,6 +213,17 @@ func TestCreateRevokeQuery(t *testing.T) { }), expected: fmt.Sprintf(`REVOKE ALL PRIVILEGES ON TABLE %[1]s."o2",%[1]s."o1" FROM %s`, pq.QuoteIdentifier(databaseName), pq.QuoteIdentifier(roleName)), }, + { + resource: schema.TestResourceDataRaw(t, resourcePostgreSQLGrant().Schema, map[string]interface{}{ + "object_type": "column", + "objects": []interface{}{"o1"}, + "schema": databaseName, + "columns": tableColumns, + "role": roleName, + "privileges": []interface{}{"SELECT"}, + }), + expected: fmt.Sprintf(`REVOKE SELECT (col2,col1) ON TABLE %[1]s."o1" FROM %s`, pq.QuoteIdentifier(databaseName), pq.QuoteIdentifier(roleName)), + }, { resource: schema.TestResourceDataRaw(t, resourcePostgreSQLGrant().Schema, map[string]interface{}{ "object_type": "foreign_data_wrapper", @@ -305,6 +333,82 @@ func TestAccPostgresqlGrant(t *testing.T) { }) } +func TestAccPostgresqlGrantColumns(t *testing.T) { + skipIfNotAcc(t) + + dbSuffix, teardown := setupTestDatabase(t, true, true) + defer teardown() + + testTables := []string{"test_schema.test_table", "test_schema.test_table2"} + createTestTables(t, dbSuffix, testTables, "") + + dbName, roleName := getTestDBNames(dbSuffix) + + var testGrant = fmt.Sprintf(` + resource "postgresql_grant" "test" { + database = "%s" + role = "%s" + schema = "test_schema" + object_type = "column" + objects = ["test_table"] + columns = %%s + privileges = %%s + } + `, dbName, roleName) + + resource.Test(t, resource.TestCase{ + PreCheck: func() { + testAccPreCheck(t) + testCheckCompatibleVersion(t, featurePrivileges) + }, + Providers: testAccProviders, + Steps: []resource.TestStep{ + { + Config: fmt.Sprintf(testGrant, `["test_column_one", "test_column_two"]`, `["SELECT"]`), + Check: resource.ComposeTestCheckFunc( + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.#", "1"), + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.4260833613", "test_table"), + resource.TestCheckResourceAttr("postgresql_grant.test", "privileges.3138006342", "SELECT"), + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"SELECT"}, []string{"test_column_one"}) + }, + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"SELECT"}, []string{"test_column_one", "test_column_two"}) + }, + ), + }, + { + Config: fmt.Sprintf(testGrant, `["test_column_one", "test_column_two"]`, `["INSERT"]`), + Check: resource.ComposeTestCheckFunc( + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.#", "1"), + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.4260833613", "test_table"), + resource.TestCheckResourceAttr("postgresql_grant.test", "privileges.892623219", "INSERT"), + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"INSERT"}, []string{`"test_column_one"`}) + }, + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"INSERT"}, []string{`"test_column_one"`, `"test_column_two"`}) + }, + ), + }, + { + Config: fmt.Sprintf(testGrant, `["test_column_one", "test_column_two"]`, `["UPDATE"]`), + Check: resource.ComposeTestCheckFunc( + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.#", "1"), + resource.TestCheckResourceAttr("postgresql_grant.test", "objects.4260833613", "test_table"), + resource.TestCheckResourceAttr("postgresql_grant.test", "privileges.1759376126", "UPDATE"), + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"UPDATE"}, []string{"test_column_one"}) + }, + func(*terraform.State) error { + return testCheckColumnPrivileges(t, dbName, roleName, []string{testTables[0]}, []string{"UPDATE"}, []string{"test_column_one", "test_column_two"}) + }, + ), + }, + }, + }) +} + func TestAccPostgresqlGrantObjects(t *testing.T) { skipIfNotAcc(t) @@ -455,6 +559,67 @@ func TestAccPostgresqlGrantObjectsError(t *testing.T) { }) } +func TestAccPostgresqlGrantColumnsError(t *testing.T) { + skipIfNotAcc(t) + + resource.Test(t, resource.TestCase{ + PreCheck: func() { + testAccPreCheck(t) + testCheckCompatibleVersion(t, featurePrivileges) + }, + Providers: testAccProviders, + Steps: []resource.TestStep{ + { + Config: `resource "postgresql_grant" "test" { + database = "test_db" + role = "test_role" + schema = "test_schema" + object_type = "column" + objects = ["o1", "o2"] + columns = ["col1", "col2"] + privileges = ["SELECT"] + }`, + ExpectError: regexp.MustCompile("must specify exactly 1 table in the `objects` field when `object_type` is `column`"), + }, + { + Config: `resource "postgresql_grant" "test" { + database = "test_db" + role = "test_role" + schema = "test_schema" + object_type = "column" + objects = ["o1"] + columns = ["col1", "col2"] + privileges = ["SELECT", "INSERT"] + }`, + ExpectError: regexp.MustCompile("must specify exactly 1 `privileges` when `object_type` is `column`"), + }, + { + Config: `resource "postgresql_grant" "test" { + database = "test_db" + role = "test_role" + schema = "test_schema" + object_type = "column" + objects = ["o1"] + privileges = ["SELECT"] + }`, + ExpectError: regexp.MustCompile("must specify `columns` when `object_type` is `column`"), + }, + { + Config: `resource "postgresql_grant" "test" { + database = "test_db" + role = "test_role" + schema = "test_schema" + object_type = "table" + objects = ["o1"] + columns = ["col1", "col2"] + privileges = ["SELECT"] + }`, + ExpectError: regexp.MustCompile("cannot specify `columns` when `object_type` is not `column`"), + }, + }, + }) +} + func TestAccPostgresqlGrantPublic(t *testing.T) { skipIfNotAcc(t) diff --git a/postgresql/utils_test.go b/postgresql/utils_test.go index b53d4290..9bbb2aa6 100644 --- a/postgresql/utils_test.go +++ b/postgresql/utils_test.go @@ -5,6 +5,7 @@ import ( "fmt" "os" "strconv" + "strings" "testing" "time" @@ -166,7 +167,7 @@ func createTestTables(t *testing.T, dbSuffix string, tables []string, owner stri } for _, table := range tables { - if _, err := db.Exec(fmt.Sprintf("CREATE TABLE %s (val text)", table)); err != nil { + if _, err := db.Exec(fmt.Sprintf("CREATE TABLE %s (val text, test_column_one text, test_column_two text)", table)); err != nil { t.Fatalf("could not create test table in db %s: %v", dbName, err) } if owner != "" { @@ -260,3 +261,34 @@ func testCheckTablesPrivileges(t *testing.T, dbName, roleName string, tables []s } return nil } + +func testCheckColumnPrivileges(t *testing.T, dbName, roleName string, tables []string, allowedPrivileges []string, columns []string) error { + db := connectAsTestRole(t, roleName, dbName) + defer db.Close() + + columnValues := []string{} + for _, col := range columns { + columnValues = append(columnValues, fmt.Sprint("'", col, "'")) + } + + updateColumnValues := []string{} + for i, _ := range columns { + updateColumnValues = append(updateColumnValues, fmt.Sprint(columns[i], " = ", columnValues[i])) + } + + for _, table := range tables { //TODO adapt these queries to table + queries := map[string]string{ + "SELECT": fmt.Sprintf("SELECT %s FROM %s", strings.Join(columns, ", "), table), + "INSERT": fmt.Sprintf("INSERT INTO %s(%s) VALUES (%s)", table, strings.Join(columns, ", "), strings.Join(columnValues, ", ")), + "UPDATE": fmt.Sprintf("UPDATE %s SET %s", table, strings.Join(updateColumnValues, ", ")), + //"REFERENCES": fmt.Sprintf("DELETE FROM %s", table), //TODO Changeme + } + + for queryType, query := range queries { + if err := testHasGrantForQuery(db, query, sliceContainsStr(allowedPrivileges, queryType)); err != nil { + return err + } + } + } + return nil +} diff --git a/website/docs/r/postgresql_grant.html.markdown b/website/docs/r/postgresql_grant.html.markdown index eb907b52..09b4d210 100644 --- a/website/docs/r/postgresql_grant.html.markdown +++ b/website/docs/r/postgresql_grant.html.markdown @@ -13,10 +13,12 @@ The ``postgresql_grant`` resource creates and manages privileges given to a user See [PostgreSQL documentation](https://www.postgresql.org/docs/current/sql-grant.html) ~> **Note:** This resource needs Postgresql version 9 or above. +~> **Note:** Using column & table grants on the _same_ table with the _same_ privileges can lead to unexpected behaviours. ## Usage ```hcl +# Grant SELECT privileges on 2 tables resource "postgresql_grant" "readonly_tables" { database = "test_db" role = "test_role" @@ -25,6 +27,17 @@ resource "postgresql_grant" "readonly_tables" { objects = ["table1", "table2"] privileges = ["SELECT"] } + +# Grant SELECT & INSERT privileges on 2 columns in 1 table +resource "postgresql_grant" "read_insert_column" { + database = "test_db" + role = "test_role" + schema = "public" + object_type = "column" + objects = ["table1"] + columns = ["col1", "col2"] + privileges = ["UPDATE", "INSERT"] +} ``` ## Argument Reference @@ -32,9 +45,10 @@ resource "postgresql_grant" "readonly_tables" { * `role` - (Required) The name of the role to grant privileges on, Set it to "public" for all roles. * `database` - (Required) The database to grant privileges on for this role. * `schema` - The database schema to grant privileges on for this role (Required except if object_type is "database") -* `object_type` - (Required) The PostgreSQL object type to grant the privileges on (one of: database, schema, table, sequence, function, foreign_data_wrapper, foreign_server). +* `object_type` - (Required) The PostgreSQL object type to grant the privileges on (one of: database, schema, table, sequence, function, foreign_data_wrapper, foreign_server, column). * `privileges` - (Required) The list of privileges to grant. There are different kinds of privileges: SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER, CREATE, CONNECT, TEMPORARY, EXECUTE, and USAGE. An empty list could be provided to revoke all privileges for this role. -* `objects` - (Optional) The objects upon which to grant the privileges. An empty list (the default) means to grant permissions on *all* objects of the specified type. You cannot specify this option if the `object_type` is `database` or `schema`. +* `objects` - (Optional) The objects upon which to grant the privileges. An empty list (the default) means to grant permissions on *all* objects of the specified type. You cannot specify this option if the `object_type` is `database` or `schema`. When `object_type` is `column`, only one value is allowed. +* `columns` - (Optional) The columns upon which to grant the privileges. Required when `object_type` is `column`. You cannot specify this option if the `object_type` is not `column`. * `with_grant_option` - (Optional) Whether the recipient of these privileges can grant the same privileges to others. Defaults to false.