├── .clang-format ├── .gitignore ├── LICENCE ├── Makefile ├── README.md ├── gp_relaccess_stats.control ├── sql ├── gp_relaccess_stats--1.0--1.1.sql └── gp_relaccess_stats--1.1.sql ├── src └── gp_relaccess_stats.c └── test ├── expected └── gp_relaccess_stats.out └── sql └── gp_relaccess_stats.sql /.clang-format: -------------------------------------------------------------------------------- 1 | BasedOnStyle: LLVM 2 | SortIncludes: false 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.o 2 | *.so 3 | .vscode 4 | compile_commands.json 5 | results 6 | -------------------------------------------------------------------------------- /LICENCE: -------------------------------------------------------------------------------- 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 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "{}" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright {yyyy} {name of copyright owner} 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULE_big = gp_relaccess_stats 2 | OBJS = ./src/gp_relaccess_stats.o 3 | EXTENSION = gp_relaccess_stats 4 | EXTVERSION = 1.0 5 | DATA = $(wildcard sql/*--*.sql) 6 | REGRESS = gp_relaccess_stats 7 | REGRESS_OPTS = --inputdir=test/ 8 | PGFILEDESC = "gp_relaccess_stats - facility to track how and when tables, partitions or views were accessed" 9 | PG_CXXFLAGS += $(COMMON_CPP_FLAGS) 10 | PG_CONFIG = pg_config 11 | PGXS := $(shell $(PG_CONFIG) --pgxs) 12 | include $(PGXS) 13 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # gp_relaccess_stats: Table access monitoring tool for Greenplum 2 | 3 | ## Features 4 | gp_relaccess_stats is an extension that records access statistics for Greenplum tables and views. Allowing users to see what objects were used, when and by whom. For example, this allows DBAs to find objects that are not used anymore or objects that are being misused. 5 | 6 | Features include: 7 | * support of both tables (regular, external or partitioned) and views 8 | * separate tracking of select, insert, update and delete queries 9 | * separate tracking of last read and write timestamps 10 | * tracking of the last user who accessed the object 11 | * per-database configuration 12 | * in-memory stats survive server restarts (but not crashes) 13 | 14 | ### Supported versions and platforms 15 | For now it is being tested only for GP6 and Linux. Though, there are no apparent reasons why it should not be working on newer GP versions (or even PG with slight code modification) or other OSes. 16 | 17 | ### Installation 18 | Install from source: 19 | ```bash 20 | # get the source code somewhere 21 | git clone git@github.com:Smyatkin-Maxim/gp_relaccess_stats.git 22 | cd gp_relaccess_stats 23 | # Build it. Building would require GP installed nearby and sourcing greenplum_path.sh 24 | source /greenplum_path.sh 25 | make && make install 26 | ``` 27 | 28 | ### Configuration 29 | As this extension does extensive usage of hooks and shared memory, you need to load gp_relaccess_stats.so on start-up: 30 | ``` 31 | gpconfig -c shared_preload_libraries -v 'gp_relaccess_stats' && gpstop -ra 32 | ``` 33 | gp_relaccess_stats configuration parameters: 34 | | **Parameter** | **Type** | **Default** | **Default** | 35 | | ---------------- | --------------- | ------------ | ------------ | 36 | | `gp_relaccess_stats.enabled` | bool | false | Using `gp_relaccess_stats.enabled` you can enable/disable stats collection either globally or for each database separately. The second option is preferred.| 37 | | `gp_relaccess_stats.max_tables` | integer | 65536 | `gp_relaccess_stats.max_tables` is a hard limit on how many tables can be cached in shared memory. Feel free to make this number higher if necessary, as the overhead is only about 160 bytes per table. Note, that stats cache for a specific table is evicted from memory any time you execute `relaccess_stats_update()` or `relaccess_stats_dump()` and new tables can be recorded. If you call these functions often enough, there is no need for high gp_relaccess_stats.max_tables| 38 | | `gp_relaccess_stats.dump_on_overflow` | bool | false | This parameter configures what happens in case `gp_relaccess_stats.max_tables` was not enough. If set to `true`, `relaccess_stats_dump()` will be called implicitly and stats cache will be freed. Otherwice, you will get a WARNING saying that there is no room for new stats. Is this case, stats for some tables will be lost.| 39 | 40 | ### Usage 41 | The first thing you need to do after `CREATE EXTENSION` and configuring - execute `SELECT relaccess_stats_init();` in a specific database. This function will fill `relaccess_stats` table with empty stats for each table and partition in this database. This is optional, but will come handy when you try to find tables that haven't been used recently, for example. 42 | 43 | Then, either manually or with a cron job start executing `select relaccess_stats_update()`. This function takes all stats cached in shared memory and all stats stored in pg_stat dir (e.g, dumps after restarts, or when `max_tables` was exceeded) and upserts them into `relaccess_stats` table. 44 | 45 | The `relaccess_stats` table itself looks like this: 46 | | **Column** | **Description** | 47 | | ---------------- | --------------- | 48 | | relid | OID of the relation | 49 | | relname | Name of the relation at last access | 50 | | last_reader_id | OID of user who read the table last | 51 | | last_writer_id | OID of user who wrote the table last | 52 | | last_read | Timestamp of the most recent select | 53 | | last_write | Timestamp of the most recent insert/delete/update/truncate | 54 | | n_select_queries | | 55 | | n_select_queries | | 56 | | n_select_queries | | 57 | | n_select_queries | | 58 | | n_truncate_queries | | 59 | 60 | **NOTE**: n_*_queries columns count the number of queries executed, not the number of rows read, inserted, deleted or updated. 61 | 62 | This table has a view associated with it: `relaccess_stats_root_tables_aggregated`. This view has exactly same columns, however it only shows partitioned tables. To be more specific, it shows aggregated stats for each partitioned table. 63 | For example, if we have 1 insert into `tbl1_prt_1` and 3 inserts into `tbl1_prt_2`, then `select * from relaccess_stats_root_tables_aggregated where relname = 'tbl1'` will show us only root table with n_insert_queries = 4. This view, however, has some limitations. See the next section for more detail. 64 | 65 | Another useful function is `relaccess_stats_dump()`, which simply moves cached stats from shared memory to temporary files in pg_stat directory. This function is cheaper than `relaccess_stats_update` but will evict stats cache if needed. Though, stats in temporary files can also get lost. Hence, it is recommended to stick with frequent `select relaccess_stats_update()` calls. 66 | 67 | To better understand when it's time to dump or update the stats one might check `select relaccess.relaccess_stats_fillfactor();`. It will show current usage of stats hash table in percents. For example if shared memory for our relaccess hash table is 70% full we will get relaccess_stats_fillfactor=70. It would be a good idea to dump or update when fillfactor is around 70%. 68 | 69 | ### Limitations and gotchas 70 | There is a number of interesting edge-cases in this simple extension: 71 | * `relaccess_stats_root_tables_aggregated` shows info only about tables that exist **now**. We simply can`t get information about inheritance relationship for deleted tables. 72 | * Stats don't rollback on savepoint rollback. We will see n_select_queries incremented by 2 in the following case: 73 | ```sql 74 | BEGIN; 75 | SELECT * FROM tbl; 76 | SAVEPOINT sp; 77 | SELECT * FROM tbl; 78 | ROLLBACK TO SAVEPOINT sp; 79 | COMMIT; 80 | ``` 81 | There is no technical reason for this limitation. It cat be fixed when there will be need for that. 82 | * Update stats often! Otherwise, data can be lost if any of it happens: 1) there was a crash, 2) `max_tables` exceeded w/o `dump_on_overflow`, 3) temporary pg_stat dir got cleaned. 83 | * no `truncate only` support. There is a TODO in code in case it is ever needed. 84 | * Updates and Deletes also increment n_select_queries. Every update and delete also read the table. That is, n_select_queries get incremented as well. If you need **only** selects, query like this `SELECT n_select_queries - (n_update_queries + n_delete_queries) ... FROM relaccess_stats ...;`. For this same reason last_read and last_reader_id change on update and delete queries. 85 | * view = view + tables. It looks like whenever you select from view, n_select_queries get incremented for both the view and tables it references. 86 | * obviously, we don't know any timestamps before we started tracking. So, the first timestamps are initialized with 0 (something around year 2000), which means those tables haven't been accessed since gp_relaccess_stats was enabled. 87 | -------------------------------------------------------------------------------- /gp_relaccess_stats.control: -------------------------------------------------------------------------------- 1 | # gp_relaccess_stats extension 2 | comment = 'gp_relaccess_stats - facility to track how and when tables, partitions or views were accesseds' 3 | default_version = '1.1' 4 | module_pathname = '$libdir/gp_relaccess_stats' 5 | relocatable = true 6 | trusted = true 7 | -------------------------------------------------------------------------------- /sql/gp_relaccess_stats--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | /* gp_relaccess_stats--1.0--1.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION gp_relaccess_stats UPDATE TO '1.1'" to load this file. \quit 5 | 6 | DROP VIEW relaccess.relaccess_stats_root_tables_aggregated; 7 | 8 | ALTER TABLE relaccess.relaccess_stats ALTER COLUMN n_select_queries TYPE int8; 9 | ALTER TABLE relaccess.relaccess_stats ALTER COLUMN n_insert_queries TYPE int8; 10 | ALTER TABLE relaccess.relaccess_stats ALTER COLUMN n_update_queries TYPE int8; 11 | ALTER TABLE relaccess.relaccess_stats ALTER COLUMN n_delete_queries TYPE int8; 12 | ALTER TABLE relaccess.relaccess_stats ALTER COLUMN n_truncate_queries TYPE int8; 13 | 14 | -- This utility view shows **ONLY** stats on **EXISTING** partitioned tables in aggregated form 15 | CREATE VIEW relaccess.relaccess_stats_root_tables_aggregated AS ( 16 | WITH RECURSIVE parents AS ( 17 | SELECT inhrelid AS child, inhparent AS parent FROM pg_inherits 18 | UNION ALL 19 | SELECT prev.child, next.inhparent AS parent FROM parents AS prev JOIN pg_inherits AS next ON prev.parent = next.inhrelid 20 | ), part_to_root_mapping AS ( 21 | SELECT DISTINCT child AS partid, min(parent) OVER (partition BY child) AS rootid FROM parents 22 | ), parts_including_roots AS ( 23 | SELECT rootid as partid, rootid FROM (SELECT DISTINCT rootid FROM part_to_root_mapping) AS p 24 | UNION 25 | SELECT * FROM part_to_root_mapping 26 | ), with_root_id AS ( 27 | SELECT part_tbl.rootid, stats.* FROM relaccess.relaccess_stats stats JOIN parts_including_roots part_tbl ON (stats.relid = part_tbl.partid) 28 | ), without_last_user AS ( 29 | SELECT rootid AS relid, 30 | rootid::regclass::text AS relname, 31 | max(last_read) AS last_read, 32 | max(last_write) AS last_write, 33 | sum(n_select_queries) AS n_select_queries, 34 | sum(n_insert_queries) AS n_insert_queries, 35 | sum(n_update_queries) AS n_update_queries, 36 | sum(n_delete_queries) AS n_delete_queries, 37 | sum(n_truncate_queries) AS n_truncate_queries 38 | FROM with_root_id outer_tbl GROUP BY rootid 39 | ) 40 | SELECT relid, 41 | relname, 42 | (SELECT last_reader_id FROM with_root_id w WHERE w.rootid = wo.relid AND wo.last_read = w.last_read LIMIT 1) AS last_reader_id, 43 | (SELECT last_writer_id FROM with_root_id w WHERE w.rootid = wo.relid AND wo.last_write = w.last_write LIMIT 1) AS last_writer_id, 44 | last_read, 45 | last_write, 46 | n_select_queries, 47 | n_insert_queries, 48 | n_update_queries, 49 | n_delete_queries, 50 | n_truncate_queries 51 | FROM without_last_user wo 52 | ); -------------------------------------------------------------------------------- /sql/gp_relaccess_stats--1.1.sql: -------------------------------------------------------------------------------- 1 | /* gp_relaccess_stats--1.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION gp_relaccess_stats" to load this file. \quit 5 | 6 | CREATE SCHEMA IF NOT EXISTS relaccess; 7 | 8 | CREATE TABLE relaccess.relaccess_stats ( 9 | relid Oid, 10 | relname Name, 11 | last_reader_id Oid, 12 | last_writer_id Oid, 13 | last_read timestamptz, 14 | last_write timestamptz, 15 | n_select_queries int8, 16 | n_insert_queries int8, 17 | n_update_queries int8, 18 | n_delete_queries int8, 19 | n_truncate_queries int8 20 | ) DISTRIBUTED BY (relid); 21 | 22 | CREATE FUNCTION relaccess.relaccess_stats_dump() 23 | RETURNS void 24 | AS 'MODULE_PATHNAME', 'relaccess_stats_dump' 25 | LANGUAGE C VOLATILE EXECUTE ON MASTER; 26 | 27 | CREATE FUNCTION relaccess.relaccess_stats_update() 28 | RETURNS void 29 | AS 'MODULE_PATHNAME', 'relaccess_stats_update' 30 | LANGUAGE C VOLATILE EXECUTE ON MASTER; 31 | 32 | CREATE FUNCTION relaccess.relaccess_stats_fillfactor() 33 | RETURNS INT2 34 | AS 'MODULE_PATHNAME', 'relaccess_stats_fillfactor' 35 | LANGUAGE C VOLATILE EXECUTE ON MASTER; 36 | 37 | CREATE FUNCTION relaccess.__get_db_stats_from_dump() 38 | RETURNS SETOF relaccess.relaccess_stats 39 | AS 'MODULE_PATHNAME', 'relaccess_stats_from_dump' 40 | LANGUAGE C VOLATILE EXECUTE ON MASTER; 41 | 42 | CREATE FUNCTION relaccess.__relaccess_upsert_from_dump_file() RETURNS VOID 43 | LANGUAGE plpgsql VOLATILE AS 44 | $func$ 45 | BEGIN 46 | EXECUTE 'DROP TABLE IF EXISTS relaccess_stats_tmp'; 47 | EXECUTE 'CREATE TEMP TABLE relaccess_stats_tmp (LIKE relaccess.relaccess_stats) distributed by (relid)'; 48 | EXECUTE 'DROP TABLE IF EXISTS relaccess_stats_tmp_aggregated'; 49 | EXECUTE 'CREATE TEMP TABLE relaccess_stats_tmp_aggregated (LIKE relaccess.relaccess_stats) distributed by (relid)'; 50 | EXECUTE 'INSERT INTO relaccess_stats_tmp SELECT * FROM relaccess.__get_db_stats_from_dump()'; 51 | EXECUTE 'WITH aggregated_wo_relname_and_user AS ( 52 | SELECT relid, max(last_read) AS last_read, max(last_write) AS last_write, sum(n_select_queries) AS n_select_queries, 53 | sum(n_insert_queries) AS n_insert_queries, sum(n_update_queries) AS n_update_queries, sum(n_delete_queries) AS n_delete_queries, sum(n_truncate_queries) AS n_truncate_queries 54 | FROM relaccess_stats_tmp GROUP BY relid 55 | ) 56 | INSERT INTO relaccess_stats_tmp_aggregated 57 | SELECT relid, 58 | (SELECT relname FROM relaccess_stats_tmp w WHERE w.relid = wo.relid AND greatest(wo.last_read, wo.last_write) IN (w.last_read, w.last_write) LIMIT 1) AS relname, 59 | (SELECT last_reader_id FROM relaccess_stats_tmp w WHERE w.relid = wo.relid AND wo.last_read = w.last_read LIMIT 1) AS last_reader_id, 60 | (SELECT last_writer_id FROM relaccess_stats_tmp w WHERE w.relid = wo.relid AND wo.last_write = w.last_write LIMIT 1) AS last_writer_id, 61 | last_read, 62 | last_write, 63 | n_select_queries, 64 | n_insert_queries, 65 | n_update_queries, 66 | n_delete_queries, 67 | n_truncate_queries FROM aggregated_wo_relname_and_user AS wo'; 68 | EXECUTE 'DROP TABLE IF EXISTS relaccess_stats_tmp'; 69 | EXECUTE 'INSERT INTO relaccess.relaccess_stats 70 | SELECT relid, relname, last_reader_id, last_writer_id, last_read, last_write, 0, 0, 0, 0, 0 71 | FROM relaccess_stats_tmp_aggregated stage 72 | WHERE NOT EXISTS ( 73 | SELECT 1 FROM relaccess.relaccess_stats orig WHERE orig.relid = stage.relid)'; 74 | EXECUTE 'UPDATE relaccess.relaccess_stats orig SET 75 | relname = stage.relname, 76 | n_select_queries = orig.n_select_queries + stage.n_select_queries, 77 | n_insert_queries = orig.n_insert_queries + stage.n_insert_queries, 78 | n_update_queries = orig.n_update_queries + stage.n_update_queries, 79 | n_delete_queries = orig.n_delete_queries + stage.n_delete_queries, 80 | n_truncate_queries = orig.n_truncate_queries + stage.n_truncate_queries 81 | FROM relaccess_stats_tmp_aggregated stage 82 | WHERE orig.relid = stage.relid'; 83 | EXECUTE 'UPDATE relaccess.relaccess_stats orig SET 84 | last_reader_id = stage.last_reader_id, last_read = stage.last_read 85 | FROM relaccess_stats_tmp_aggregated stage 86 | WHERE orig.relid = stage.relid AND orig.last_read < stage.last_read'; 87 | EXECUTE 'UPDATE relaccess.relaccess_stats orig SET 88 | last_writer_id = stage.last_writer_id, last_write = stage.last_write 89 | FROM relaccess_stats_tmp_aggregated stage 90 | WHERE orig.relid = stage.relid AND orig.last_write < stage.last_write'; 91 | EXECUTE 'DROP TABLE IF EXISTS relaccess_stats_tmp_aggregated'; 92 | END 93 | $func$; 94 | 95 | CREATE FUNCTION relaccess.relaccess_stats_init() RETURNS VOID AS 96 | $$ 97 | WITH relations AS ( 98 | SELECT oid as relid, relname, relowner FROM pg_catalog.pg_class WHERE relkind in ('r', 'v', 'm', 'f', 'p') 99 | ) 100 | INSERT INTO relaccess.relaccess_stats 101 | SELECT relid, relname, relowner, relowner, '2000-01-01 03:00:00', '2000-01-01 03:00:00', 0, 0, 0, 0, 0 102 | FROM relations AS all_rels WHERE NOT EXISTS(SELECT 1 FROM relaccess.relaccess_stats orig WHERE orig.relid = all_rels.relid); 103 | $$ LANGUAGE SQL VOLATILE; 104 | 105 | -- This utility view shows **ONLY** stats on **EXISTING** partitioned tables in aggregated form 106 | CREATE VIEW relaccess.relaccess_stats_root_tables_aggregated AS ( 107 | WITH RECURSIVE parents AS ( 108 | SELECT inhrelid AS child, inhparent AS parent FROM pg_inherits 109 | UNION ALL 110 | SELECT prev.child, next.inhparent AS parent FROM parents AS prev JOIN pg_inherits AS next ON prev.parent = next.inhrelid 111 | ), part_to_root_mapping AS ( 112 | SELECT DISTINCT child AS partid, min(parent) OVER (partition BY child) AS rootid FROM parents 113 | ), parts_including_roots AS ( 114 | SELECT rootid as partid, rootid FROM (SELECT DISTINCT rootid FROM part_to_root_mapping) AS p 115 | UNION 116 | SELECT * FROM part_to_root_mapping 117 | ), with_root_id AS ( 118 | SELECT part_tbl.rootid, stats.* FROM relaccess.relaccess_stats stats JOIN parts_including_roots part_tbl ON (stats.relid = part_tbl.partid) 119 | ), without_last_user AS ( 120 | SELECT rootid AS relid, 121 | rootid::regclass::text AS relname, 122 | max(last_read) AS last_read, 123 | max(last_write) AS last_write, 124 | sum(n_select_queries) AS n_select_queries, 125 | sum(n_insert_queries) AS n_insert_queries, 126 | sum(n_update_queries) AS n_update_queries, 127 | sum(n_delete_queries) AS n_delete_queries, 128 | sum(n_truncate_queries) AS n_truncate_queries 129 | FROM with_root_id outer_tbl GROUP BY rootid 130 | ) 131 | SELECT relid, 132 | relname, 133 | (SELECT last_reader_id FROM with_root_id w WHERE w.rootid = wo.relid AND wo.last_read = w.last_read LIMIT 1) AS last_reader_id, 134 | (SELECT last_writer_id FROM with_root_id w WHERE w.rootid = wo.relid AND wo.last_write = w.last_write LIMIT 1) AS last_writer_id, 135 | last_read, 136 | last_write, 137 | n_select_queries, 138 | n_insert_queries, 139 | n_update_queries, 140 | n_delete_queries, 141 | n_truncate_queries 142 | FROM without_last_user wo 143 | ); 144 | -------------------------------------------------------------------------------- /src/gp_relaccess_stats.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "access/xact.h" 3 | #include "access/hash.h" 4 | #include "catalog/objectaccess.h" 5 | #include "catalog/pg_database.h" 6 | #include "cdb/cdbvars.h" 7 | #include "commands/dbcommands.h" 8 | #include "executor/executor.h" 9 | #include "executor/spi.h" 10 | #include "funcapi.h" 11 | #include "miscadmin.h" 12 | #include "pg_config_ext.h" 13 | #include "pgstat.h" 14 | #include "storage/ipc.h" 15 | #include "storage/lwlock.h" 16 | #include "storage/shmem.h" 17 | #include "storage/spin.h" 18 | #include "utils/builtins.h" 19 | #include "utils/datetime.h" 20 | #include "utils/lsyscache.h" 21 | #include "utils/memutils.h" 22 | #include "utils/timestamp.h" 23 | #include "tcop/utility.h" 24 | 25 | #include 26 | #include 27 | 28 | /** 29 | * gp_relaccess_stats collects runtime access stats on db objects: relations and 30 | * views. Stats include last read and write timestamps, last user, last known 31 | * relname and number of select, insert, update, delete or truncate queries. 32 | * Only committed actions are recorded. 33 | * 34 | * To track those actions we use: 35 | * - ExecutorCheckPerms hook for select, insert, update and delete statements 36 | * - ProcessUtility hook for truncate statements 37 | * 38 | * Intermediate data is stored in three hash tables. 39 | * One lives in shared memory and is cleaned only when dumped to disc: 40 | * - relaccesses - represents all recorded accesses since last dump to disc. 41 | * And two live in coordinator`s local memory and are cleaned on every commit 42 | * or rollback: 43 | * - local_access_entries - represent all record accesses in for this 44 | * transaction only 45 | * - relname_cache - maps relid to relname for relations used in this 46 | * transaction only 47 | * 48 | * Ultimately all recorded stats should end up in relaccess_stats table when a 49 | * user executes relaccess_stats_update(). But any intermediate stats will be 50 | * dumped to disc. This might happen for either or those reasons: 51 | * - shmem is exceeded 52 | * - server is restarted 53 | * - manual execution of relaccess_stats_dump() 54 | * In this case stats are offloaded to disc into pg_stat directory into separate 55 | * file per each tracked database: pg_stat/relaccess_stats_dump_.csv Those 56 | * files are upserted into relaccess_stats when relaccess_stats_update() is 57 | * called 58 | */ 59 | 60 | PG_MODULE_MAGIC; 61 | 62 | void _PG_init(void); 63 | void _PG_fini(void); 64 | PG_FUNCTION_INFO_V1(relaccess_stats_update); 65 | PG_FUNCTION_INFO_V1(relaccess_stats_dump); 66 | PG_FUNCTION_INFO_V1(relaccess_stats_fillfactor); 67 | PG_FUNCTION_INFO_V1(relaccess_stats_from_dump); 68 | 69 | static void relaccess_stats_update_internal(void); 70 | static void relaccess_dump_to_files(bool only_this_db); 71 | static void relaccess_dump_to_files_internal(HTAB *files); 72 | static void relaccess_upsert_from_file(void); 73 | static void relaccess_shmem_startup(void); 74 | static void relaccess_shmem_shutdown(int code, Datum arg); 75 | static uint32 relaccess_hash_fn(const void *key, Size keysize); 76 | static int relaccess_match_fn(const void *key1, const void *key2, Size keysize); 77 | static uint32 local_relaccess_hash_fn(const void *key, Size keysize); 78 | static int local_relaccess_match_fn(const void *key1, const void *key2, 79 | Size keysize); 80 | static bool collect_relaccess_hook(List *rangeTable, bool ereport_on_violation); 81 | static void relaccess_xact_callback(XactEvent event, void *arg); 82 | static void collect_truncate_hook(Node *parsetree, const char *queryString, 83 | ProcessUtilityContext context, 84 | ParamListInfo params, DestReceiver *dest, 85 | char *completionTag); 86 | static void relaccess_executor_end_hook(QueryDesc *query_desc); 87 | static void relaccess_drop_hook(ObjectAccessType access, Oid classId, 88 | Oid objectId, int subId, void *arg); 89 | static void memorize_local_access_entry(Oid relid, AclMode perms); 90 | static void update_relname_cache(Oid relid, char *relname); 91 | static StringInfoData get_dump_filename(Oid dbid); 92 | 93 | static shmem_startup_hook_type prev_shmem_startup_hook = NULL; 94 | static ExecutorCheckPerms_hook_type prev_check_perms_hook = NULL; 95 | static ProcessUtility_hook_type next_ProcessUtility_hook = NULL; 96 | static ExecutorEnd_hook_type prev_ExecutorEnd_hook = NULL; 97 | static object_access_hook_type prev_object_access_hook = NULL; 98 | 99 | typedef struct relaccessHashKey { 100 | Oid dbid; 101 | Oid relid; 102 | } relaccessHashKey; 103 | 104 | typedef struct relaccessEntry { 105 | relaccessHashKey key; 106 | char relname[NAMEDATALEN]; 107 | Oid last_reader_id; 108 | Oid last_writer_id; 109 | TimestampTz last_read; 110 | TimestampTz last_write; 111 | int64 n_select; 112 | int64 n_insert; 113 | int64 n_update; 114 | int64 n_delete; 115 | int64 n_truncate; 116 | } relaccessEntry; 117 | 118 | typedef struct relaccessGlobalData { 119 | LWLock *relaccess_ht_lock; 120 | LWLock *relaccess_file_lock; 121 | } relaccessGlobalData; 122 | 123 | typedef struct localAccessKey { 124 | Oid relid; 125 | int stmt_cnt; 126 | } localAccessKey; 127 | 128 | typedef struct localAccessEntry { 129 | localAccessKey key; 130 | Oid last_reader_id, last_writer_id; 131 | Timestamp last_read, last_write; 132 | AclMode perms; 133 | } localAccessEntry; 134 | 135 | typedef struct relnameCacheEntry { 136 | Oid relid; 137 | char relname[NAMEDATALEN]; 138 | } relnameCacheEntry; 139 | 140 | typedef struct fileDumpEntry { 141 | Oid dbid; 142 | char *filename; 143 | FILE *file; 144 | } fileDumpEntry; 145 | 146 | static int32 relaccess_size; 147 | static bool dump_on_overflow; 148 | static bool is_enabled; 149 | static relaccessGlobalData *data; 150 | static HTAB *relaccesses; 151 | static HTAB *local_access_entries = NULL; 152 | static const int32 LOCAL_HTAB_SZ = 128; 153 | static HTAB *relname_cache = NULL; 154 | static const int32 RELCACHE_SZ = 16; 155 | static const int32 FILE_CACHE_SZ = 16; 156 | static int stmt_counter = 0; 157 | static bool had_ht_overflow = false; 158 | 159 | #define IS_POSTGRES_DB \ 160 | (strcmp("postgres", get_database_name(MyDatabaseId)) == 0) 161 | 162 | #define is_write(perms) \ 163 | (((perms) & (ACL_INSERT | ACL_UPDATE | ACL_DELETE | ACL_TRUNCATE)) != 0) 164 | 165 | #define is_read(perms) (!is_write(perms) && ((perms)&ACL_SELECT) != 0) 166 | 167 | static void relaccess_shmem_startup() { 168 | bool found; 169 | HASHCTL info; 170 | 171 | if (prev_shmem_startup_hook) 172 | prev_shmem_startup_hook(); 173 | 174 | LWLockAcquire(AddinShmemInitLock, LW_EXCLUSIVE); 175 | 176 | data = (relaccessGlobalData *)(ShmemInitStruct( 177 | "relaccess_stats", sizeof(relaccessGlobalData), &found)); 178 | if (!found) { 179 | data->relaccess_ht_lock = LWLockAssign(); 180 | data->relaccess_file_lock = LWLockAssign(); 181 | } 182 | 183 | memset(&info, 0, sizeof(info)); 184 | info.keysize = sizeof(relaccessHashKey); 185 | info.entrysize = sizeof(relaccessEntry); 186 | info.hash = relaccess_hash_fn; 187 | info.match = relaccess_match_fn; 188 | relaccesses = ShmemInitHash( 189 | "relaccess_stats hash", relaccess_size, relaccess_size, &info, 190 | (HASH_ELEM | HASH_FUNCTION | HASH_COMPARE | HASH_FIXED_SIZE)); 191 | 192 | LWLockRelease(AddinShmemInitLock); 193 | 194 | if (!IsUnderPostmaster) { 195 | on_shmem_exit(relaccess_shmem_shutdown, (Datum)0); 196 | } 197 | } 198 | 199 | static void relaccess_shmem_shutdown(int code, Datum arg) { 200 | if (code || !data || !relaccesses) { 201 | return; 202 | } 203 | LWLockAcquire(data->relaccess_ht_lock, LW_EXCLUSIVE); 204 | relaccess_dump_to_files(false); 205 | LWLockRelease(data->relaccess_ht_lock); 206 | } 207 | 208 | static uint32 relaccess_hash_fn(const void *key, Size keysize) { 209 | const relaccessHashKey *k = (const relaccessHashKey *)key; 210 | return hash_uint32((uint32)k->dbid) ^ hash_uint32((uint32)k->relid); 211 | } 212 | 213 | static int relaccess_match_fn(const void *key1, const void *key2, 214 | Size keysize) { 215 | const relaccessHashKey *k1 = (const relaccessHashKey *)key1; 216 | const relaccessHashKey *k2 = (const relaccessHashKey *)key2; 217 | return (k1->dbid == k2->dbid && k1->relid == k2->relid) ? 0 : 1; 218 | } 219 | 220 | static uint32 local_relaccess_hash_fn(const void *key, Size keysize) { 221 | const localAccessKey *k = (const localAccessKey *)key; 222 | return hash_uint32((uint32)k->stmt_cnt) ^ hash_uint32((uint32)k->relid); 223 | } 224 | 225 | static int local_relaccess_match_fn(const void *key1, const void *key2, 226 | Size keysize) { 227 | const localAccessKey *k1 = (const localAccessKey *)key1; 228 | const localAccessKey *k2 = (const localAccessKey *)key2; 229 | return (k1->stmt_cnt == k2->stmt_cnt && k1->relid == k2->relid) ? 0 : 1; 230 | } 231 | 232 | void _PG_init(void) { 233 | Size size; 234 | if (Gp_role != GP_ROLE_DISPATCH) { 235 | return; 236 | } 237 | if (!process_shared_preload_libraries_in_progress) { 238 | return; 239 | } 240 | 241 | DefineCustomIntVariable( 242 | "gp_relaccess_stats.max_tables", 243 | "Sets the maximum number of tables cached by gp_relaccess_stats.", NULL, 244 | &relaccess_size, 65536, 128, INT_MAX, PGC_POSTMASTER, 0, NULL, NULL, 245 | NULL); 246 | 247 | DefineCustomBoolVariable("gp_relaccess_stats.dump_on_overflow", 248 | "Selects whether we should dump to .csv in case " 249 | "gp_relaccess_stats.max_tables is exceeded.", 250 | NULL, &dump_on_overflow, false, PGC_SIGHUP, 0, NULL, 251 | NULL, NULL); 252 | 253 | DefineCustomBoolVariable( 254 | "gp_relaccess_stats.enabled", 255 | "Collect table access stats globally or for a specific database. " 256 | "Note that shared memory is initialized indepemdent of this argument.", 257 | NULL, &is_enabled, false, PGC_SUSET, 0, NULL, NULL, NULL); 258 | 259 | prev_shmem_startup_hook = shmem_startup_hook; 260 | shmem_startup_hook = relaccess_shmem_startup; 261 | prev_check_perms_hook = ExecutorCheckPerms_hook; 262 | ExecutorCheckPerms_hook = collect_relaccess_hook; 263 | next_ProcessUtility_hook = ProcessUtility_hook; 264 | ProcessUtility_hook = collect_truncate_hook; 265 | prev_ExecutorEnd_hook = ExecutorEnd_hook; 266 | ExecutorEnd_hook = relaccess_executor_end_hook; 267 | prev_object_access_hook = object_access_hook; 268 | object_access_hook = relaccess_drop_hook; 269 | RequestAddinLWLocks(2); 270 | size = MAXALIGN(sizeof(relaccessGlobalData)); 271 | size = add_size(size, 272 | hash_estimate_size(relaccess_size, sizeof(relaccessEntry))); 273 | RequestAddinShmemSpace(size); 274 | RegisterXactCallback(relaccess_xact_callback, NULL); 275 | HASHCTL ctl; 276 | MemSet(&ctl, 0, sizeof(ctl)); 277 | ctl.keysize = sizeof(localAccessKey); 278 | ctl.entrysize = sizeof(localAccessEntry); 279 | ctl.hash = local_relaccess_hash_fn; 280 | ctl.match = local_relaccess_match_fn; 281 | local_access_entries = 282 | hash_create("Transaction-wide relaccess entries", LOCAL_HTAB_SZ, &ctl, 283 | HASH_ELEM | HASH_FUNCTION | HASH_COMPARE); 284 | MemSet(&ctl, 0, sizeof(ctl)); 285 | ctl.keysize = sizeof(Oid); 286 | ctl.entrysize = sizeof(relnameCacheEntry); 287 | ctl.hash = oid_hash; 288 | relname_cache = hash_create("Transaction-wide relation name cache", 289 | RELCACHE_SZ, &ctl, HASH_ELEM | HASH_FUNCTION); 290 | } 291 | 292 | void _PG_fini(void) { 293 | if (Gp_role != GP_ROLE_DISPATCH) { 294 | return; 295 | } 296 | shmem_startup_hook = prev_shmem_startup_hook; 297 | ExecutorCheckPerms_hook = prev_check_perms_hook; 298 | ProcessUtility_hook = next_ProcessUtility_hook; 299 | ExecutorEnd_hook = prev_ExecutorEnd_hook; 300 | object_access_hook = prev_object_access_hook; 301 | } 302 | 303 | static bool collect_relaccess_hook(List *rangeTable, 304 | bool ereport_on_violation) { 305 | if (prev_check_perms_hook && 306 | !prev_check_perms_hook(rangeTable, ereport_on_violation)) { 307 | return false; 308 | } 309 | if (Gp_role == GP_ROLE_DISPATCH && is_enabled) { 310 | ListCell *l; 311 | foreach (l, rangeTable) { 312 | RangeTblEntry *rte = (RangeTblEntry *)lfirst(l); 313 | if (rte->rtekind != RTE_RELATION) { 314 | continue; 315 | } 316 | Oid relid = rte->relid; 317 | AclMode requiredPerms = rte->requiredPerms; 318 | if (is_read(requiredPerms) || is_write(requiredPerms)) { 319 | memorize_local_access_entry(relid, requiredPerms); 320 | update_relname_cache(relid, NULL); 321 | } 322 | } 323 | } 324 | return true; 325 | } 326 | 327 | static void collect_truncate_hook(Node *parsetree, const char *queryString, 328 | ProcessUtilityContext context, 329 | ParamListInfo params, DestReceiver *dest, 330 | char *completionTag) { 331 | if (nodeTag(parsetree) == T_TruncateStmt && is_enabled && 332 | Gp_role == GP_ROLE_DISPATCH) { 333 | TruncateStmt *stmt = (TruncateStmt *)parsetree; 334 | ListCell *cell; 335 | /** 336 | * TODO: TRUNCATE may be called with ONLY option which limits it only to 337 | *the root partition. Otherwise it will truncate all child partitions. We 338 | *might wish to track the difference by explicitly adding records for each 339 | *truncated partition in the future if it proves useful 340 | **/ 341 | foreach (cell, stmt->relations) { 342 | RangeVar *rv = lfirst(cell); 343 | Relation rel; 344 | rel = heap_openrv(rv, AccessExclusiveLock); 345 | Oid relid = rel->rd_id; 346 | heap_close(rel, NoLock); 347 | memorize_local_access_entry(relid, ACL_TRUNCATE); 348 | update_relname_cache(relid, rv->relname); 349 | } 350 | } 351 | if (next_ProcessUtility_hook) { 352 | next_ProcessUtility_hook(parsetree, queryString, context, params, dest, 353 | completionTag); 354 | } else { 355 | standard_ProcessUtility(parsetree, queryString, context, params, dest, 356 | completionTag); 357 | } 358 | } 359 | 360 | #define UPDATE_STAT(lowercase, uppercase) \ 361 | dst_entry->n_##lowercase += (src_entry->perms & ACL_##uppercase ? 1 : 0) 362 | 363 | // if there is a better way to cleanup a postgres hashtable 364 | // w/o recreating it, I didn't find it 365 | #define CLEAR_HTAB(entryType, hmap, key_name) \ 366 | { \ 367 | HASH_SEQ_STATUS hash_seq; \ 368 | entryType *src_entry; \ 369 | hash_seq_init(&hash_seq, hmap); \ 370 | while ((src_entry = hash_seq_search(&hash_seq)) != NULL) { \ 371 | bool found; \ 372 | hash_search(hmap, &src_entry->key_name, HASH_REMOVE, &found); \ 373 | Assert(found); \ 374 | } \ 375 | } 376 | 377 | static void relaccess_xact_callback(XactEvent event, void *arg) { 378 | if (Gp_role != GP_ROLE_DISPATCH || !is_enabled) { 379 | return; 380 | } 381 | // TODO: add support for savepoint rollbacks 382 | Assert(GetCurrentTransactionNestLevel() == 1); 383 | if (event == XACT_EVENT_COMMIT) { 384 | HASH_SEQ_STATUS hash_seq; 385 | localAccessEntry *src_entry; 386 | hash_seq_init(&hash_seq, local_access_entries); 387 | LWLockAcquire(data->relaccess_ht_lock, LW_EXCLUSIVE); 388 | while ((src_entry = hash_seq_search(&hash_seq)) != NULL) { 389 | bool found; 390 | relaccessHashKey key; 391 | key.dbid = MyDatabaseId; 392 | key.relid = src_entry->key.relid; 393 | long n_access_records = hash_get_num_entries(relaccesses); 394 | relaccessEntry *dst_entry = NULL; 395 | Assert(n_access_records <= relaccess_size); 396 | if (n_access_records == relaccess_size) { 397 | // no room for new entries. Perhaps this relid is already being tracked? 398 | dst_entry = 399 | (relaccessEntry *)hash_search(relaccesses, &key, HASH_FIND, &found); 400 | } else { 401 | dst_entry = (relaccessEntry *)hash_search(relaccesses, &key, 402 | HASH_ENTER_NULL, &found); 403 | } 404 | if (dst_entry || dump_on_overflow) { 405 | if (!dst_entry) { 406 | // we are out of shared memory and need to dump 407 | relaccess_dump_to_files(false); 408 | // we MUST have enough space now, unless we were unable to dump 409 | dst_entry = (relaccessEntry *)hash_search(relaccesses, &key, 410 | HASH_ENTER_NULL, &found); 411 | if (!dst_entry) { 412 | // still no memory left 413 | if (!had_ht_overflow) { 414 | elog(WARNING, ("gp_relaccess_stats.max_tables is exceeded and we " 415 | "are unable to dump hashtables to disk. " 416 | "Will start loosing some relaccess stats")); 417 | had_ht_overflow = true; 418 | } 419 | continue; 420 | } else { 421 | had_ht_overflow = false; 422 | } 423 | } 424 | if (!found) { 425 | dst_entry->last_reader_id = InvalidOid; 426 | dst_entry->last_writer_id = InvalidOid; 427 | dst_entry->last_read = 0; 428 | dst_entry->last_write = 0; 429 | dst_entry->n_select = 0; 430 | dst_entry->n_insert = 0; 431 | dst_entry->n_update = 0; 432 | dst_entry->n_delete = 0; 433 | dst_entry->n_truncate = 0; 434 | } 435 | UPDATE_STAT(select, SELECT); 436 | UPDATE_STAT(insert, INSERT); 437 | UPDATE_STAT(update, UPDATE); 438 | UPDATE_STAT(delete, DELETE); 439 | UPDATE_STAT(truncate, TRUNCATE); 440 | if (src_entry->last_read > dst_entry->last_read) { 441 | dst_entry->last_read = src_entry->last_read; 442 | dst_entry->last_reader_id = src_entry->last_reader_id; 443 | } 444 | if (src_entry->last_write > dst_entry->last_write) { 445 | dst_entry->last_write = src_entry->last_write; 446 | dst_entry->last_writer_id = src_entry->last_writer_id; 447 | } 448 | relnameCacheEntry *namecache_entry = (relnameCacheEntry *)hash_search( 449 | relname_cache, &key.relid, HASH_ENTER, &found); 450 | Assert(namecache_entry); 451 | strlcpy(dst_entry->relname, namecache_entry->relname, 452 | sizeof(dst_entry->relname)); 453 | } else { 454 | if (!had_ht_overflow) { 455 | elog(WARNING, "gp_relaccess_stats.max_tables is exceeded! New table " 456 | "events will be lost. " 457 | "Please execute relaccess_stats_update() and consider " 458 | "setting a hihger value"); 459 | } 460 | had_ht_overflow = true; 461 | } 462 | } 463 | LWLockRelease(data->relaccess_ht_lock); 464 | CLEAR_HTAB(localAccessEntry, local_access_entries, key); 465 | CLEAR_HTAB(relnameCacheEntry, relname_cache, relid); 466 | } else if (event == XACT_EVENT_ABORT) { 467 | CLEAR_HTAB(localAccessEntry, local_access_entries, key); 468 | CLEAR_HTAB(relnameCacheEntry, relname_cache, relid); 469 | } 470 | } 471 | 472 | Datum relaccess_stats_update(PG_FUNCTION_ARGS) { 473 | relaccess_stats_update_internal(); 474 | PG_RETURN_VOID(); 475 | } 476 | 477 | Datum relaccess_stats_dump(PG_FUNCTION_ARGS) { 478 | LWLockAcquire(data->relaccess_ht_lock, LW_EXCLUSIVE); 479 | relaccess_dump_to_files(true); 480 | LWLockRelease(data->relaccess_ht_lock); 481 | PG_RETURN_VOID(); 482 | } 483 | 484 | Datum relaccess_stats_fillfactor(PG_FUNCTION_ARGS) { 485 | LWLockAcquire(data->relaccess_ht_lock, LW_SHARED); 486 | int16_t fillfactor = hash_get_num_entries(relaccesses) * 100 / relaccess_size; 487 | LWLockRelease(data->relaccess_ht_lock); 488 | PG_RETURN_INT16(fillfactor); 489 | } 490 | 491 | Datum relaccess_stats_from_dump(PG_FUNCTION_ARGS) { 492 | FuncCallContext *funcctx; 493 | List *stats_entries = NIL; 494 | 495 | if (SRF_IS_FIRSTCALL()) { 496 | funcctx = SRF_FIRSTCALL_INIT(); 497 | MemoryContext oldcontext = 498 | MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); 499 | TupleDesc tupdesc = CreateTemplateTupleDesc(11, false /* hasoid */); 500 | TupleDescInitEntry(tupdesc, (AttrNumber)1, "relid", OIDOID, -1 /* typmod */, 501 | 0 /* attdim */); 502 | TupleDescInitEntry(tupdesc, (AttrNumber)2, "relname", NAMEOID, 503 | -1 /* typmod */, 0 /* attdim */); 504 | TupleDescInitEntry(tupdesc, (AttrNumber)3, "last_reader_id", OIDOID, 505 | -1 /* typmod */, 0 /* attdim */); 506 | TupleDescInitEntry(tupdesc, (AttrNumber)4, "last_writer_id", OIDOID, 507 | -1 /* typmod */, 0 /* attdim */); 508 | TupleDescInitEntry(tupdesc, (AttrNumber)5, "last_read", TIMESTAMPTZOID, 509 | -1 /* typmod */, 0 /* attdim */); 510 | TupleDescInitEntry(tupdesc, (AttrNumber)6, "last_write", TIMESTAMPTZOID, 511 | -1 /* typmod */, 0 /* attdim */); 512 | TupleDescInitEntry(tupdesc, (AttrNumber)7, "n_select_queries", INT8OID, 513 | -1 /* typmod */, 0 /* attdim */); 514 | TupleDescInitEntry(tupdesc, (AttrNumber)8, "n_insert_queries", INT8OID, 515 | -1 /* typmod */, 0 /* attdim */); 516 | TupleDescInitEntry(tupdesc, (AttrNumber)9, "n_update_queries", INT8OID, 517 | -1 /* typmod */, 0 /* attdim */); 518 | TupleDescInitEntry(tupdesc, (AttrNumber)10, "n_delete_queries", INT8OID, 519 | -1 /* typmod */, 0 /* attdim */); 520 | TupleDescInitEntry(tupdesc, (AttrNumber)11, "n_truncate_queries", INT8OID, 521 | -1 /* typmod */, 0 /* attdim */); 522 | funcctx->tuple_desc = BlessTupleDesc(tupdesc); 523 | StringInfoData dump_file = get_dump_filename(MyDatabaseId); 524 | FILE *dump = AllocateFile(dump_file.data, "rb"); 525 | pfree(dump_file.data); 526 | if (dump) { 527 | while (true) { 528 | relaccessEntry *entry = palloc(sizeof(relaccessEntry)); 529 | if (fread(entry, sizeof(relaccessEntry), 1, dump) != 1) { 530 | pfree(entry); 531 | break; 532 | } 533 | stats_entries = lappend(stats_entries, entry); 534 | } 535 | FreeFile(dump); 536 | } 537 | funcctx->user_fctx = stats_entries; 538 | MemoryContextSwitchTo(oldcontext); 539 | } 540 | 541 | funcctx = SRF_PERCALL_SETUP(); 542 | stats_entries = (List *)funcctx->user_fctx; 543 | 544 | while (true) { 545 | if (stats_entries == NIL) { 546 | SRF_RETURN_DONE(funcctx); 547 | } 548 | relaccessEntry *entry = linitial(stats_entries); 549 | stats_entries = list_delete_first(stats_entries); 550 | Datum values[11]; 551 | bool nulls[11]; 552 | MemSet(nulls, 0, sizeof(nulls)); 553 | values[0] = ObjectIdGetDatum(entry->key.relid); 554 | values[1] = CStringGetDatum(entry->relname); 555 | values[2] = ObjectIdGetDatum(entry->last_reader_id); 556 | values[3] = ObjectIdGetDatum(entry->last_writer_id); 557 | values[4] = TimestampTzGetDatum(entry->last_read); 558 | values[5] = TimestampTzGetDatum(entry->last_write); 559 | values[6] = Int64GetDatum(entry->n_select); 560 | values[7] = Int64GetDatum(entry->n_insert); 561 | values[8] = Int64GetDatum(entry->n_update); 562 | values[9] = Int64GetDatum(entry->n_delete); 563 | values[10] = Int64GetDatum(entry->n_truncate); 564 | HeapTuple tuple = heap_form_tuple(funcctx->tuple_desc, values, nulls); 565 | Datum result = HeapTupleGetDatum(tuple); 566 | funcctx->user_fctx = stats_entries; 567 | /** NOTE: Cannot delete entry from this iteration right now. 568 | * For now let's rely on multi_call_memory_ctx until there is a proven 569 | * memory problem with this codepath 570 | */ 571 | // pfree(entry); 572 | SRF_RETURN_NEXT(funcctx, result); 573 | } 574 | } 575 | 576 | static void relaccess_stats_update_internal() { 577 | LWLockAcquire(data->relaccess_ht_lock, LW_EXCLUSIVE); 578 | relaccess_dump_to_files(true); 579 | LWLockRelease(data->relaccess_ht_lock); 580 | relaccess_upsert_from_file(); 581 | } 582 | 583 | static void add_file_dump_entry(Oid dbid, HTAB *ht) { 584 | bool found; 585 | fileDumpEntry *file_entry = hash_search(ht, &dbid, HASH_ENTER, &found); 586 | if (!found) { 587 | file_entry->dbid = dbid; 588 | StringInfoData filename = get_dump_filename(file_entry->dbid); 589 | file_entry->filename = filename.data; 590 | file_entry->file = AllocateFile(file_entry->filename, "ab"); 591 | } 592 | } 593 | 594 | static void relaccess_dump_to_files(bool only_this_db) { 595 | HTAB *file_mapping; 596 | HASHCTL ctl; 597 | MemSet(&ctl, 0, sizeof(ctl)); 598 | ctl.keysize = sizeof(Oid); 599 | ctl.entrysize = sizeof(fileDumpEntry); 600 | ctl.hash = oid_hash; 601 | file_mapping = hash_create("Relaccess dump files", FILE_CACHE_SZ, &ctl, 602 | HASH_ELEM | HASH_FUNCTION); 603 | LWLockAcquire(data->relaccess_file_lock, LW_EXCLUSIVE); 604 | if (only_this_db) { 605 | add_file_dump_entry(MyDatabaseId, file_mapping); 606 | } else { 607 | HASH_SEQ_STATUS hash_seq; 608 | relaccessEntry *access_entry; 609 | hash_seq_init(&hash_seq, relaccesses); 610 | while ((access_entry = hash_seq_search(&hash_seq)) != NULL) { 611 | add_file_dump_entry(access_entry->key.dbid, file_mapping); 612 | } 613 | } 614 | relaccess_dump_to_files_internal(file_mapping); 615 | HASH_SEQ_STATUS hash_seq; 616 | hash_seq_init(&hash_seq, file_mapping); 617 | fileDumpEntry *entry; 618 | while ((entry = hash_seq_search(&hash_seq)) != NULL) { 619 | FreeFile(entry->file); 620 | pfree(entry->filename); 621 | } 622 | LWLockRelease(data->relaccess_file_lock); 623 | hash_destroy(file_mapping); 624 | } 625 | 626 | static void relaccess_dump_to_files_internal(HTAB *files) { 627 | HASH_SEQ_STATUS hash_seq; 628 | relaccessEntry *entry; 629 | hash_seq_init(&hash_seq, relaccesses); 630 | while ((entry = hash_seq_search(&hash_seq)) != NULL) { 631 | bool found; 632 | fileDumpEntry *dumpfile = 633 | hash_search(files, &entry->key.dbid, HASH_FIND, &found); 634 | if (!found) { 635 | // we don't want to dump events from this DB 636 | continue; 637 | } 638 | if (fwrite(entry, sizeof(relaccessEntry), 1, dumpfile->file) != 1) { 639 | hash_seq_term(&hash_seq); 640 | ereport(WARNING, 641 | (errcode_for_file_access(), 642 | errmsg("could not write gp_relaccess_stats file \"%s\": %m", 643 | dumpfile->filename))); 644 | break; 645 | } 646 | hash_search(relaccesses, &entry->key, HASH_REMOVE, &found); 647 | had_ht_overflow = false; 648 | } 649 | } 650 | 651 | static void relaccess_upsert_from_file() { 652 | int ret; 653 | if ((ret = SPI_connect()) < 0) { 654 | elog(ERROR, "SPI connect failure - returned %d", ret); 655 | } 656 | LWLockAcquire(data->relaccess_file_lock, LW_EXCLUSIVE); 657 | StringInfoData filename = get_dump_filename(MyDatabaseId); 658 | StringInfoData query; 659 | initStringInfo(&query); 660 | appendStringInfo(&query, 661 | "SELECT relaccess.__relaccess_upsert_from_dump_file()"); 662 | ret = SPI_execute(query.data, false, 1); 663 | unlink(filename.data); 664 | LWLockRelease(data->relaccess_file_lock); 665 | SPI_finish(); 666 | if (ret < 0) { 667 | elog(ERROR, "SPI execute failure - returned %d", ret); 668 | } 669 | } 670 | 671 | static void update_relname_cache(Oid relid, char *relname) { 672 | bool found; 673 | relnameCacheEntry *relname_entry = (relnameCacheEntry *)hash_search( 674 | relname_cache, &relid, HASH_ENTER, &found); 675 | if (!found) { 676 | relname_entry->relid = relid; 677 | if (!relname) { 678 | strlcpy(relname_entry->relname, get_rel_name(relid), 679 | sizeof(relname_entry->relname)); 680 | } else { 681 | strlcpy(relname_entry->relname, relname, sizeof(relname_entry->relname)); 682 | } 683 | } else { 684 | /** 685 | * NOTE: as we don't handle the 'else' clause here, there will be cases when 686 | * we write outdated table names, like below: 687 | * BEGIN; 688 | * INSERT INTO tbl VALUES (1); 689 | * ALTER TABLE tbl RENAME TO new_tbl; 690 | * SELECT * FROM new_tbl; 691 | * COMMIT; 692 | * In this case both INSERT and SELECT stmts would be counted with the 693 | * old'tbl' name, as we don't update our cache for already known relids in 694 | * the same transaction. This is a deliberate decision for performance 695 | * reasons. 696 | */ 697 | } 698 | } 699 | 700 | static void memorize_local_access_entry(Oid relid, AclMode perms) { 701 | bool found; 702 | localAccessKey key; 703 | key.stmt_cnt = stmt_counter; 704 | key.relid = relid; 705 | localAccessEntry *entry = (localAccessEntry *)hash_search( 706 | local_access_entries, &key, HASH_ENTER, &found); 707 | if (!found) { 708 | entry->last_read = entry->last_write = InvalidOid; 709 | entry->perms = perms; 710 | entry->last_read = 0; 711 | entry->last_write = 0; 712 | } else { 713 | entry->perms |= perms; 714 | } 715 | TimestampTz curts = GetCurrentTimestamp(); 716 | if (is_read(perms)) { 717 | entry->last_reader_id = GetUserId(); 718 | entry->last_read = curts; 719 | } 720 | if (is_write(perms)) { 721 | entry->last_writer_id = GetUserId(); 722 | entry->last_write = curts; 723 | } 724 | } 725 | 726 | static void relaccess_executor_end_hook(QueryDesc *query_desc) { 727 | if (prev_ExecutorEnd_hook) { 728 | prev_ExecutorEnd_hook(query_desc); 729 | } else { 730 | standard_ExecutorEnd(query_desc); 731 | } 732 | // Unfortunately, we cannot safely rely on gp_command_counter as 733 | // it is being incremented more than once for many statements. 734 | // So we have to maintain our own statement counter. 735 | stmt_counter++; 736 | } 737 | 738 | static StringInfoData get_dump_filename(Oid dbid) { 739 | StringInfoData filename; 740 | initStringInfoOfSize(&filename, 256); 741 | appendStringInfo(&filename, "%s/relaccess_stats_dump_%d.csv", 742 | PGSTAT_STAT_PERMANENT_DIRECTORY, dbid); 743 | return filename; 744 | } 745 | 746 | static void relaccess_drop_hook(ObjectAccessType access, Oid classId, 747 | Oid objectId, int subId, void *arg) { 748 | if (prev_object_access_hook) { 749 | prev_object_access_hook(access, classId, objectId, subId, arg); 750 | } 751 | // we don't want shared memory and .csv files hanging around forever 752 | // for databases that we've dropped. 753 | // This function cleans up both files and shmem 754 | if (classId == DatabaseRelationId && access == OAT_DROP) { 755 | LWLockAcquire(data->relaccess_ht_lock, LW_EXCLUSIVE); 756 | HASH_SEQ_STATUS hash_seq; 757 | relaccessEntry *entry; 758 | hash_seq_init(&hash_seq, relaccesses); 759 | while ((entry = hash_seq_search(&hash_seq)) != NULL) { 760 | if (entry->key.dbid == objectId) { 761 | bool found; 762 | hash_search(relaccesses, &entry->key, HASH_REMOVE, &found); 763 | had_ht_overflow = false; 764 | } 765 | } 766 | LWLockRelease(data->relaccess_ht_lock); 767 | LWLockAcquire(data->relaccess_file_lock, LW_EXCLUSIVE); 768 | StringInfoData filename = get_dump_filename(objectId); 769 | unlink(filename.data); 770 | pfree(filename.data); 771 | LWLockRelease(data->relaccess_file_lock); 772 | } 773 | } -------------------------------------------------------------------------------- /test/expected/gp_relaccess_stats.out: -------------------------------------------------------------------------------- 1 | GP_IGNORE: formatted by atmsort.pm 2 | CREATE EXTENSION gp_relaccess_stats; 3 | -- get rid of NOTICEs 4 | SET client_min_messages TO WARNING; 5 | SET search_path TO relaccess; 6 | DROP TABLE IF EXISTS tbl1 CASCADE; 7 | DROP TABLE IF EXISTS tbl2 CASCADE; 8 | DROP TABLE IF EXISTS tbl3 CASCADE; 9 | DROP TABLE IF EXISTS tbl4 CASCADE; 10 | DROP TABLE IF EXISTS new_tbl1 CASCADE; 11 | DROP TABLE IF EXISTS p3_sales CASCADE; 12 | DROP TABLE IF EXISTS public.last_usr_checks CASCADE; 13 | DROP USER IF EXISTS select_usr; 14 | DROP USER IF EXISTS update_usr; 15 | DROP USER IF EXISTS insert_usr; 16 | DROP USER IF EXISTS delete_usr; 17 | DROP USER IF EXISTS truncate_usr; 18 | -- make sure tracking is ON 19 | SET gp_relaccess_stats.enabled TO 'on'; 20 | SELECT relaccess_stats_init(); 21 | relaccess_stats_init 22 | ---------------------- 23 | 24 | (1 row) 25 | 26 | SELECT relaccess_stats_update(); 27 | relaccess_stats_update 28 | ------------------------ 29 | 30 | (1 row) 31 | 32 | TRUNCATE relaccess_stats; 33 | -- test simple actions one by one in separate transactions 34 | CREATE TABLE tbl1 (a INTEGER); 35 | INSERT INTO tbl1 VALUES(1); 36 | SELECT relaccess_stats_update(); 37 | relaccess_stats_update 38 | ------------------------ 39 | 40 | (1 row) 41 | 42 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 43 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 44 | ------------------+------------------+------------------+------------------+-------------------- 45 | 0 | 1 | 0 | 0 | 0 46 | (1 row) 47 | 48 | SELECT * FROM tbl1; 49 | a 50 | --- 51 | 1 52 | (1 row) 53 | 54 | SELECT relaccess_stats_update(); 55 | relaccess_stats_update 56 | ------------------------ 57 | 58 | (1 row) 59 | 60 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 61 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 62 | ------------------+------------------+------------------+------------------+-------------------- 63 | 1 | 1 | 0 | 0 | 0 64 | (1 row) 65 | 66 | UPDATE tbl1 SET a = -a; 67 | SELECT relaccess_stats_update(); 68 | relaccess_stats_update 69 | ------------------------ 70 | 71 | (1 row) 72 | 73 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 74 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 75 | ------------------+------------------+------------------+------------------+-------------------- 76 | 2 | 1 | 1 | 0 | 0 77 | (1 row) 78 | 79 | DELETE FROM tbl1 WHERE a < 0; 80 | SELECT relaccess_stats_update(); 81 | relaccess_stats_update 82 | ------------------------ 83 | 84 | (1 row) 85 | 86 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 87 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 88 | ------------------+------------------+------------------+------------------+-------------------- 89 | 3 | 1 | 1 | 1 | 0 90 | (1 row) 91 | 92 | TRUNCATE tbl1; 93 | SELECT relaccess_stats_update(); 94 | relaccess_stats_update 95 | ------------------------ 96 | 97 | (1 row) 98 | 99 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 100 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 101 | ------------------+------------------+------------------+------------------+-------------------- 102 | 3 | 1 | 1 | 1 | 1 103 | (1 row) 104 | 105 | -- verify that rename table works 106 | ALTER TABLE tbl1 RENAME TO new_tbl1; 107 | INSERT INTO new_tbl1 VALUES(1); 108 | SELECT relaccess_stats_update(); 109 | relaccess_stats_update 110 | ------------------------ 111 | 112 | (1 row) 113 | 114 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relname = 'tbl1'; 115 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 116 | ------------------+------------------+------------------+------------------+-------------------- 117 | (0 rows) 118 | 119 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'new_tbl1'::regclass::oid AND relname = 'new_tbl1'; 120 | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 121 | ------------------+------------------+------------------+------------------+-------------------- 122 | 3 | 2 | 1 | 1 | 1 123 | (1 row) 124 | 125 | TRUNCATE relaccess_stats; 126 | -- multitable truncate 127 | CREATE TABLE tbl1 (a integer); 128 | CREATE TABLE tbl2 (a integer); 129 | TRUNCATE tbl1, tbl2; 130 | SELECT relaccess_stats_update(); 131 | relaccess_stats_update 132 | ------------------------ 133 | 134 | (1 row) 135 | 136 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats 137 | WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1' OR relid = 'tbl2'::regclass::oid AND relname = 'tbl2' ORDER BY relname; 138 | relname | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 139 | ---------+------------------+------------------+------------------+------------------+-------------------- 140 | tbl1 | 0 | 0 | 0 | 0 | 1 141 | tbl2 | 0 | 0 | 0 | 0 | 1 142 | (2 rows) 143 | 144 | TRUNCATE relaccess_stats; 145 | -- test a more complicated statement 146 | CREATE TABLE tbl3 (a integer); 147 | CREATE TABLE tbl4 (a integer); 148 | BEGIN; 149 | -- should give +1 insert for tbl1 and +1 select for other tables 150 | INSERT INTO tbl1 SELECT * FROM tbl2 UNION SELECT * FROM tbl3 UNION SELECT * FROM tbl4; 151 | -- nothing in there before we commit 152 | SELECT relaccess_stats_update(); 153 | relaccess_stats_update 154 | ------------------------ 155 | 156 | (1 row) 157 | 158 | SELECT COUNT(*) FROM relaccess_stats WHERE relname LIKE ('tbl_'); 159 | count 160 | ------- 161 | 0 162 | (1 row) 163 | 164 | COMMIT; 165 | SELECT relaccess_stats_update(); 166 | relaccess_stats_update 167 | ------------------------ 168 | 169 | (1 row) 170 | 171 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 172 | FROM relaccess_stats WHERE relname LIKE ('tbl_') AND relname::regclass::oid = relid ORDER BY relname; 173 | relname | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 174 | ---------+------------------+------------------+------------------+------------------+-------------------- 175 | tbl1 | 0 | 1 | 0 | 0 | 0 176 | tbl2 | 1 | 0 | 0 | 0 | 0 177 | tbl3 | 1 | 0 | 0 | 0 | 0 178 | tbl4 | 1 | 0 | 0 | 0 | 0 179 | (4 rows) 180 | 181 | TRUNCATE relaccess_stats; 182 | -- test views 183 | CREATE VIEW v1_2_3 AS (SELECT * FROM tbl2 UNION SELECT * FROM tbl3 UNION SELECT * FROM tbl4); 184 | INSERT INTO tbl1 SELECT * FROM v1_2_3; 185 | SELECT relaccess_stats_update(); 186 | relaccess_stats_update 187 | ------------------------ 188 | 189 | (1 row) 190 | 191 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 192 | FROM relaccess_stats WHERE relname = 'v1_2_3' OR relname LIKE ('tbl_') ORDER BY relname; 193 | relname | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 194 | ---------+------------------+------------------+------------------+------------------+-------------------- 195 | tbl1 | 0 | 1 | 0 | 0 | 0 196 | tbl2 | 1 | 0 | 0 | 0 | 0 197 | tbl3 | 1 | 0 | 0 | 0 | 0 198 | tbl4 | 1 | 0 | 0 | 0 | 0 199 | v1_2_3 | 1 | 0 | 0 | 0 | 0 200 | (5 rows) 201 | 202 | TRUNCATE relaccess_stats; 203 | -- test timestamps difference 204 | BEGIN; 205 | INSERT INTO tbl1 VALUES (1); 206 | SELECT pg_sleep(1); 207 | pg_sleep 208 | ---------- 209 | 210 | (1 row) 211 | 212 | SELECT COUNT(*) FROM tbl1; 213 | count 214 | ------- 215 | 1 216 | (1 row) 217 | 218 | COMMIT; 219 | SELECT relaccess_stats_update(); 220 | relaccess_stats_update 221 | ------------------------ 222 | 223 | (1 row) 224 | 225 | SELECT EXTRACT(EPOCH FROM (last_read - last_write)) >= 1 FROM relaccess_stats WHERE relname = 'tbl1' AND relid = 'tbl1'::regclass::oid; 226 | ?column? 227 | ---------- 228 | t 229 | (1 row) 230 | 231 | TRUNCATE relaccess_stats; 232 | -- test nested partitions lookup 233 | BEGIN; 234 | CREATE TABLE p3_sales (id int, year int, month int, day int, 235 | region text) 236 | DISTRIBUTED BY (id) 237 | PARTITION BY RANGE (year) 238 | SUBPARTITION BY RANGE (month) 239 | SUBPARTITION TEMPLATE ( 240 | START (1) END (13) EVERY (1), 241 | DEFAULT SUBPARTITION other_months ) 242 | SUBPARTITION BY LIST (region) 243 | SUBPARTITION TEMPLATE ( 244 | SUBPARTITION usa VALUES ('usa'), 245 | SUBPARTITION europe VALUES ('europe'), 246 | SUBPARTITION asia VALUES ('asia'), 247 | DEFAULT SUBPARTITION other_regions ) 248 | ( START (2002) END (2012) EVERY (1), 249 | DEFAULT PARTITION outlying_years ); 250 | -- 3 inserts into p3_sales root table 251 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'asia' FROM generate_series(1, 100)i; 252 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'europe' FROM generate_series(1, 100)i; 253 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'usa' FROM generate_series(1, 100)i; 254 | -- insert and select to/from specific leaf level partition 255 | INSERT INTO p3_sales_1_prt_11_2_prt_12_3_prt_usa SELECT * FROM p3_sales_1_prt_11_2_prt_12_3_prt_usa; 256 | COMMIT; 257 | SELECT relaccess_stats_update(); 258 | relaccess_stats_update 259 | ------------------------ 260 | 261 | (1 row) 262 | 263 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 264 | FROM relaccess_stats WHERE relname LIKE 'p3_sales%' ORDER BY relname; 265 | relname | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 266 | --------------------------------------+------------------+------------------+------------------+------------------+-------------------- 267 | p3_sales | 0 | 3 | 0 | 0 | 0 268 | p3_sales_1_prt_11_2_prt_12_3_prt_usa | 1 | 1 | 0 | 0 | 0 269 | (2 rows) 270 | 271 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 272 | FROM relaccess_stats_root_tables_aggregated WHERE relname LIKE 'p3_sales%' ORDER BY relname; 273 | relname | n_select_queries | n_insert_queries | n_update_queries | n_delete_queries | n_truncate_queries 274 | ----------+------------------+------------------+------------------+------------------+-------------------- 275 | p3_sales | 1 | 4 | 0 | 0 | 0 276 | (1 row) 277 | 278 | -- test last_reader and last_writer 279 | CREATE USER select_usr; 280 | CREATE USER update_usr; 281 | CREATE USER insert_usr; 282 | CREATE USER delete_usr; 283 | CREATE USER truncate_usr; 284 | CREATE TABLE public.last_usr_checks(a integer); 285 | GRANT ALL ON TABLE public.last_usr_checks TO select_usr, update_usr, insert_usr, delete_usr, truncate_usr; 286 | SET ROLE select_usr; 287 | SELECT COUNT(*) FROM public.last_usr_checks; 288 | count 289 | ------- 290 | 0 291 | (1 row) 292 | 293 | RESET ROLE; 294 | SELECT relaccess_stats_update(); 295 | relaccess_stats_update 296 | ------------------------ 297 | 298 | (1 row) 299 | 300 | SELECT (SELECT last_reader_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'select_usr'); 301 | ?column? 302 | ---------- 303 | t 304 | (1 row) 305 | 306 | SET ROLE insert_usr; 307 | INSERT INTO public.last_usr_checks VALUES (-1), (0), (1); 308 | RESET ROLE; 309 | SELECT relaccess_stats_update(); 310 | relaccess_stats_update 311 | ------------------------ 312 | 313 | (1 row) 314 | 315 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'insert_usr'); 316 | ?column? 317 | ---------- 318 | t 319 | (1 row) 320 | 321 | SET ROLE update_usr; 322 | UPDATE public.last_usr_checks SET a = a*10 WHERE a < 0; 323 | RESET ROLE; 324 | SELECT relaccess_stats_update(); 325 | relaccess_stats_update 326 | ------------------------ 327 | 328 | (1 row) 329 | 330 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'update_usr'); 331 | ?column? 332 | ---------- 333 | t 334 | (1 row) 335 | 336 | SET ROLE delete_usr; 337 | DELETE FROM public.last_usr_checks WHERE a >= 0; 338 | RESET ROLE; 339 | SELECT relaccess_stats_update(); 340 | relaccess_stats_update 341 | ------------------------ 342 | 343 | (1 row) 344 | 345 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'delete_usr'); 346 | ?column? 347 | ---------- 348 | t 349 | (1 row) 350 | 351 | SET ROLE truncate_usr; 352 | TRUNCATE public.last_usr_checks; 353 | RESET ROLE; 354 | SELECT relaccess_stats_update(); 355 | relaccess_stats_update 356 | ------------------------ 357 | 358 | (1 row) 359 | 360 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'truncate_usr'); 361 | ?column? 362 | ---------- 363 | t 364 | (1 row) 365 | 366 | RESET ROLE; 367 | -- make sure we can turn it OFF 368 | SET gp_relaccess_stats.enabled TO 'off'; 369 | SELECT relaccess_stats_update(); 370 | relaccess_stats_update 371 | ------------------------ 372 | 373 | (1 row) 374 | 375 | TRUNCATE relaccess_stats; 376 | SELECT * FROM tbl1; 377 | a 378 | --- 379 | 1 380 | (1 row) 381 | 382 | SELECT relaccess_stats_update(); 383 | relaccess_stats_update 384 | ------------------------ 385 | 386 | (1 row) 387 | 388 | SELECT count(*) FROM relaccess_stats; 389 | count 390 | ------- 391 | 0 392 | (1 row) 393 | 394 | RESET gp_relaccess_stats.enabled; 395 | DROP TABLE tbl1 CASCADE; 396 | DROP TABLE tbl2 CASCADE; 397 | DROP TABLE tbl3 CASCADE; 398 | DROP TABLE tbl4 CASCADE; 399 | DROP TABLE new_tbl1 CASCADE; 400 | DROP TABLE p3_sales CASCADE; 401 | DROP TABLE public.last_usr_checks CASCADE; 402 | DROP USER select_usr; 403 | DROP USER update_usr; 404 | DROP USER insert_usr; 405 | DROP USER delete_usr; 406 | DROP USER truncate_usr; 407 | -------------------------------------------------------------------------------- /test/sql/gp_relaccess_stats.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION gp_relaccess_stats; 2 | 3 | -- get rid of NOTICEs 4 | SET client_min_messages TO WARNING; 5 | SET search_path TO relaccess; 6 | DROP TABLE IF EXISTS tbl1 CASCADE; 7 | DROP TABLE IF EXISTS tbl2 CASCADE; 8 | DROP TABLE IF EXISTS tbl3 CASCADE; 9 | DROP TABLE IF EXISTS tbl4 CASCADE; 10 | DROP TABLE IF EXISTS new_tbl1 CASCADE; 11 | DROP TABLE IF EXISTS p3_sales CASCADE; 12 | DROP TABLE IF EXISTS public.last_usr_checks CASCADE; 13 | DROP USER IF EXISTS select_usr; 14 | DROP USER IF EXISTS update_usr; 15 | DROP USER IF EXISTS insert_usr; 16 | DROP USER IF EXISTS delete_usr; 17 | DROP USER IF EXISTS truncate_usr; 18 | 19 | -- make sure tracking is ON 20 | SET gp_relaccess_stats.enabled TO 'on'; 21 | SELECT relaccess_stats_init(); 22 | SELECT relaccess_stats_update(); 23 | TRUNCATE relaccess_stats; 24 | 25 | -- test simple actions one by one in separate transactions 26 | CREATE TABLE tbl1 (a INTEGER); 27 | 28 | INSERT INTO tbl1 VALUES(1); 29 | SELECT relaccess_stats_update(); 30 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 31 | 32 | SELECT * FROM tbl1; 33 | SELECT relaccess_stats_update(); 34 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 35 | 36 | UPDATE tbl1 SET a = -a; 37 | SELECT relaccess_stats_update(); 38 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 39 | 40 | DELETE FROM tbl1 WHERE a < 0; 41 | SELECT relaccess_stats_update(); 42 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 43 | 44 | TRUNCATE tbl1; 45 | SELECT relaccess_stats_update(); 46 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1'; 47 | 48 | -- verify that rename table works 49 | ALTER TABLE tbl1 RENAME TO new_tbl1; 50 | INSERT INTO new_tbl1 VALUES(1); 51 | SELECT relaccess_stats_update(); 52 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relname = 'tbl1'; 53 | SELECT n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats WHERE relid = 'new_tbl1'::regclass::oid AND relname = 'new_tbl1'; 54 | 55 | TRUNCATE relaccess_stats; 56 | -- multitable truncate 57 | CREATE TABLE tbl1 (a integer); 58 | CREATE TABLE tbl2 (a integer); 59 | TRUNCATE tbl1, tbl2; 60 | SELECT relaccess_stats_update(); 61 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries FROM relaccess_stats 62 | WHERE relid = 'tbl1'::regclass::oid AND relname = 'tbl1' OR relid = 'tbl2'::regclass::oid AND relname = 'tbl2' ORDER BY relname; 63 | 64 | TRUNCATE relaccess_stats; 65 | -- test a more complicated statement 66 | CREATE TABLE tbl3 (a integer); 67 | CREATE TABLE tbl4 (a integer); 68 | 69 | BEGIN; 70 | -- should give +1 insert for tbl1 and +1 select for other tables 71 | INSERT INTO tbl1 SELECT * FROM tbl2 UNION SELECT * FROM tbl3 UNION SELECT * FROM tbl4; 72 | -- nothing in there before we commit 73 | SELECT relaccess_stats_update(); 74 | SELECT COUNT(*) FROM relaccess_stats WHERE relname LIKE ('tbl_'); 75 | COMMIT; 76 | SELECT relaccess_stats_update(); 77 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 78 | FROM relaccess_stats WHERE relname LIKE ('tbl_') AND relname::regclass::oid = relid ORDER BY relname; 79 | 80 | TRUNCATE relaccess_stats; 81 | -- test views 82 | CREATE VIEW v1_2_3 AS (SELECT * FROM tbl2 UNION SELECT * FROM tbl3 UNION SELECT * FROM tbl4); 83 | INSERT INTO tbl1 SELECT * FROM v1_2_3; 84 | SELECT relaccess_stats_update(); 85 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 86 | FROM relaccess_stats WHERE relname = 'v1_2_3' OR relname LIKE ('tbl_') ORDER BY relname; 87 | 88 | TRUNCATE relaccess_stats; 89 | -- test timestamps difference 90 | BEGIN; 91 | INSERT INTO tbl1 VALUES (1); 92 | SELECT pg_sleep(1); 93 | SELECT COUNT(*) FROM tbl1; 94 | COMMIT; 95 | SELECT relaccess_stats_update(); 96 | SELECT EXTRACT(EPOCH FROM (last_read - last_write)) >= 1 FROM relaccess_stats WHERE relname = 'tbl1' AND relid = 'tbl1'::regclass::oid; 97 | TRUNCATE relaccess_stats; 98 | 99 | -- test nested partitions lookup 100 | BEGIN; 101 | CREATE TABLE p3_sales (id int, year int, month int, day int, 102 | region text) 103 | DISTRIBUTED BY (id) 104 | PARTITION BY RANGE (year) 105 | SUBPARTITION BY RANGE (month) 106 | SUBPARTITION TEMPLATE ( 107 | START (1) END (13) EVERY (1), 108 | DEFAULT SUBPARTITION other_months ) 109 | SUBPARTITION BY LIST (region) 110 | SUBPARTITION TEMPLATE ( 111 | SUBPARTITION usa VALUES ('usa'), 112 | SUBPARTITION europe VALUES ('europe'), 113 | SUBPARTITION asia VALUES ('asia'), 114 | DEFAULT SUBPARTITION other_regions ) 115 | ( START (2002) END (2012) EVERY (1), 116 | DEFAULT PARTITION outlying_years ); 117 | -- 3 inserts into p3_sales root table 118 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'asia' FROM generate_series(1, 100)i; 119 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'europe' FROM generate_series(1, 100)i; 120 | INSERT INTO p3_sales SELECT i, i%43+1980, i%12, i%25, 'usa' FROM generate_series(1, 100)i; 121 | -- insert and select to/from specific leaf level partition 122 | INSERT INTO p3_sales_1_prt_11_2_prt_12_3_prt_usa SELECT * FROM p3_sales_1_prt_11_2_prt_12_3_prt_usa; 123 | COMMIT; 124 | SELECT relaccess_stats_update(); 125 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 126 | FROM relaccess_stats WHERE relname LIKE 'p3_sales%' ORDER BY relname; 127 | SELECT relname, n_select_queries, n_insert_queries, n_update_queries, n_delete_queries, n_truncate_queries 128 | FROM relaccess_stats_root_tables_aggregated WHERE relname LIKE 'p3_sales%' ORDER BY relname; 129 | 130 | -- test last_reader and last_writer 131 | CREATE USER select_usr; 132 | CREATE USER update_usr; 133 | CREATE USER insert_usr; 134 | CREATE USER delete_usr; 135 | CREATE USER truncate_usr; 136 | CREATE TABLE public.last_usr_checks(a integer); 137 | GRANT ALL ON TABLE public.last_usr_checks TO select_usr, update_usr, insert_usr, delete_usr, truncate_usr; 138 | SET ROLE select_usr; 139 | SELECT COUNT(*) FROM public.last_usr_checks; 140 | RESET ROLE; 141 | SELECT relaccess_stats_update(); 142 | SELECT (SELECT last_reader_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'select_usr'); 143 | SET ROLE insert_usr; 144 | INSERT INTO public.last_usr_checks VALUES (-1), (0), (1); 145 | RESET ROLE; 146 | SELECT relaccess_stats_update(); 147 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'insert_usr'); 148 | SET ROLE update_usr; 149 | UPDATE public.last_usr_checks SET a = a*10 WHERE a < 0; 150 | RESET ROLE; 151 | SELECT relaccess_stats_update(); 152 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'update_usr'); 153 | SET ROLE delete_usr; 154 | DELETE FROM public.last_usr_checks WHERE a >= 0; 155 | RESET ROLE; 156 | SELECT relaccess_stats_update(); 157 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'delete_usr'); 158 | SET ROLE truncate_usr; 159 | TRUNCATE public.last_usr_checks; 160 | RESET ROLE; 161 | SELECT relaccess_stats_update(); 162 | SELECT (SELECT last_writer_id FROM relaccess_stats WHERE RELNAME = 'last_usr_checks') = (SELECT oid FROM pg_roles WHERE rolname = 'truncate_usr'); 163 | RESET ROLE; 164 | 165 | -- make sure we can turn it OFF 166 | SET gp_relaccess_stats.enabled TO 'off'; 167 | SELECT relaccess_stats_update(); 168 | TRUNCATE relaccess_stats; 169 | SELECT * FROM tbl1; 170 | SELECT relaccess_stats_update(); 171 | SELECT count(*) FROM relaccess_stats; 172 | RESET gp_relaccess_stats.enabled; 173 | 174 | DROP TABLE tbl1 CASCADE; 175 | DROP TABLE tbl2 CASCADE; 176 | DROP TABLE tbl3 CASCADE; 177 | DROP TABLE tbl4 CASCADE; 178 | DROP TABLE new_tbl1 CASCADE; 179 | DROP TABLE p3_sales CASCADE; 180 | DROP TABLE public.last_usr_checks CASCADE; 181 | DROP USER select_usr; 182 | DROP USER update_usr; 183 | DROP USER insert_usr; 184 | DROP USER delete_usr; 185 | DROP USER truncate_usr; 186 | 187 | --------------------------------------------------------------------------------