├── .gitignore ├── .readthedocs.yaml ├── CONTRIBUTING.md ├── LICENSE.md ├── README.md ├── docs ├── FAQ.rst ├── Makefile ├── README.md ├── architecture.rst ├── components │ ├── hypopg.rst │ ├── index.rst │ ├── introduction.rst │ ├── powa-archivist │ │ ├── configuration.rst │ │ ├── development.rst │ │ ├── index.rst │ │ └── installation.rst │ ├── powa-collector │ │ ├── index.rst │ │ └── protocol.rst │ ├── powa-web │ │ ├── deployment.rst │ │ ├── development.rst │ │ ├── index.rst │ │ └── installation.rst │ └── stats_extensions │ │ ├── index.rst │ │ ├── pg_qualstats.rst │ │ ├── pg_stat_kcache.rst │ │ ├── pg_stat_statements.rst │ │ ├── pg_track_settings.rst │ │ └── pg_wait_sampling.rst ├── conf.py ├── contributing.rst ├── debugging.rst ├── images │ ├── example_pgss.gif │ ├── hypopg_db.png │ ├── hypopg_query.png │ ├── pg_qualstats.png │ ├── pg_stat_kcache_1.png │ ├── pg_stat_kcache_2.png │ ├── pg_stat_kcache_system_resources.png │ ├── pg_stat_statements.png │ ├── pg_track_settings.png │ ├── powa_4_local.svg │ ├── powa_4_remote.svg │ ├── powa_waits_db.png │ ├── powa_waits_overview.png │ └── powa_waits_query.png ├── impact_on_perf.rst ├── index.rst ├── make.bat ├── quickstart.rst ├── releases.rst ├── releases │ ├── v2.0.rst │ ├── v3.0.0.rst │ └── v4.0.0.rst ├── remote_setup.rst ├── requirements.txt ├── security.rst └── support.rst └── img └── powa_logo.410x161.png /.gitignore: -------------------------------------------------------------------------------- 1 | *.pyc 2 | docs/_build 3 | -------------------------------------------------------------------------------- /.readthedocs.yaml: -------------------------------------------------------------------------------- 1 | # .readthedocs.yaml 2 | # Read the Docs configuration file 3 | # See https://docs.readthedocs.io/en/stable/config-file/v2.html for details 4 | 5 | # Required 6 | version: 2 7 | 8 | # Set the version of Python and other tools you might need 9 | build: 10 | os: ubuntu-22.04 11 | tools: 12 | python: "3.11" 13 | 14 | # Build documentation in the docs/ directory with Sphinx 15 | sphinx: 16 | configuration: docs/conf.py 17 | 18 | # We recommend specifying your dependencies to enable reproducible builds: 19 | # https://docs.readthedocs.io/en/stable/guides/reproducible-builds.html 20 | python: 21 | install: 22 | - requirements: docs/requirements.txt 23 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | See https://powa.readthedocs.io/en/latest/contributing.html 2 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | Copyright (c) 2014-2017, DALIBO 2 | Copyright (c) 2018-2024, The PoWA-team 3 | 4 | Permission to use, copy, modify, and distribute this software and its 5 | documentation for any purpose, without fee, and without a written agreement is 6 | hereby granted, provided that the above copyright notice and this paragraph and 7 | the following two paragraphs appear in all copies. 8 | 9 | IN NO EVENT SHALL DALIBO BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, 10 | INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF 11 | THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF DALIBO HAS BEEN ADVISED 12 | OF THE POSSIBILITY OF SUCH DAMAGE. 13 | 14 | DALIBO SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, 15 | THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. 16 | THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND DALIBO HAS NO 17 | OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR 18 | MODIFICATIONS. 19 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ![PostgreSQL Workload Analyzer](https://github.com/powa-team/powa/blob/master/img/powa_logo.410x161.png) 2 | 3 | Demo 4 | ==== 5 | 6 | You can try powa at [demo-powa.anayrat.info](https://demo-powa.anayrat.info/). 7 | Just click "Login" and try its features! Note that in order to get interesting 8 | metrics, resources have been limited on this server (2 vCPU, 384MB of RAM and 9 | 150iops for the disks). Please be patient when using it. 10 | 11 | Thanks to [Adrien Nayrat](https://blog.anayrat.info) for providing it. 12 | 13 | PostgreSQL Workload Analyzer 14 | ============================ 15 | 16 | PoWA is a PostgreSQL Workload Analyzer that gathers performance stats and 17 | provides real-time charts and graphs to help monitor and tune your PostgreSQL 18 | servers. 19 | 20 | For more information, please read: 21 | 22 | * the Documentation : https://powa.readthedocs.io/ 23 | 24 | WARNING !!! 25 | -------------- 26 | 27 | The current version PoWA is designed for **all PostgreSQL versions supported 28 | by the community**, and EOL versions down to 9.4. 29 | 30 | If you're using PostgreSQL 9.3, you should use PoWA version 1.x: 31 | * The code is here: https://github.com/powa-team/powa/tree/REL_1_STABLE 32 | * The documentation is there: https://powa.readthedocs.io/en/rel_1_stable/ 33 | 34 | Where's the code ? 35 | -------------------- 36 | 37 | This repository contains the [PoWA documentation](https://powa.readthedocs.io/). 38 | The source code is split in multiple separate projects: 39 | 40 | * [PoWA-archivist](https://github.com/powa-team/powa-archivist): the statistic collector 41 | * [PoWA-web](https://github.com/powa-team/powa-web): the graphic user interface 42 | * [pg_qualstats](https://github.com/powa-team/pg_qualstats): an extension to sample predicate statistics 43 | * [pg_stat_kcache](https://github.com/powa-team/pg_stat_kcache): an extension to sample O/S metrics 44 | 45 | Some other extensions are supported, for a complete list [please refer to the 46 | documentation](https://powa.readthedocs.io/en/latest/components/stats_extensions/index.html). 47 | -------------------------------------------------------------------------------- /docs/FAQ.rst: -------------------------------------------------------------------------------- 1 | Frequently Asked Questions 2 | ========================== 3 | 4 | Can I use PoWA on a standby server, or store the data on an external server? 5 | ---------------------------------------------------------------------------- 6 | 7 | Yes! Since version 4 of PoWA, it's possible to set up a **remote snapshotting**, 8 | thus aggregating all the performance data on a dedicated remote PostgreSQL 9 | server. This mode greatly limits the performance impact of PoWA on the 10 | configured servers and also allows to use PoWA on standby servers too. See the 11 | :ref:`remote_setup` documentation more details. 12 | 13 | Some queries don't show up in the UI 14 | ------------------------------------ 15 | 16 | That's a know limitation with the current implementation of powa-web. 17 | 18 | For now, the UI will only display information about queries that have been run 19 | on **at least** two distinct snapshots of powa-archivist (parameter 20 | `powa.frequency`). With default settings, that means you need to run activity 21 | for at least 10 minutes. 22 | 23 | This is however usually not a problem since queries only executed a few time 24 | and never again are not really a target for optimization. 25 | 26 | I ran some queries and index suggestion doesn't suggest any index 27 | ----------------------------------------------------------------- 28 | 29 | With default configuration, pg_qualstats will only sample 1% of the queries. 30 | This default value is a safeguard to avoid overhead on heavily loaded 31 | production server. However, if you're just doing some test that means that 32 | you'll miss most of the WHERE and JOIN clauses, and index suggestion won't be 33 | able to suggest indexes. 34 | 35 | If you want pg_qualstats to sample every query, you 36 | need to configure `pg_qualstats.sample_rate = 1` in the **postgresql.conf** 37 | configuration file, and reload the configuration. 38 | 39 | Please keep in mind that 40 | such a configuration can have a strong impact on the performance, especially if 41 | a lot of concurrent and fast queries are executed. 42 | -------------------------------------------------------------------------------- /docs/Makefile: -------------------------------------------------------------------------------- 1 | # Minimal makefile for Sphinx documentation 2 | # 3 | 4 | # You can set these variables from the command line, and also 5 | # from the environment for the first two. 6 | SPHINXOPTS ?= 7 | SPHINXBUILD ?= sphinx-build 8 | SOURCEDIR = . 9 | BUILDDIR = _build 10 | 11 | # Put it first so that "make" without argument is like "make help". 12 | help: 13 | @$(SPHINXBUILD) -M help "$(SOURCEDIR)" "$(BUILDDIR)" $(SPHINXOPTS) $(O) 14 | 15 | .PHONY: help Makefile 16 | 17 | html: 18 | 19 | serve: 20 | sphinx-autobuild --watch=. "$(SOURCEDIR)" "$(BUILDDIR)" $(SPHINXOPTS) 21 | 22 | # Catch-all target: route all unknown targets to Sphinx using the new 23 | # "make mode" option. $(O) is meant as a shortcut for $(SPHINXOPTS). 24 | %: Makefile 25 | @$(SPHINXBUILD) -M $@ "$(SOURCEDIR)" "$(BUILDDIR)" $(SPHINXOPTS) $(O) 26 | -------------------------------------------------------------------------------- /docs/README.md: -------------------------------------------------------------------------------- 1 | PoWA Documentation 2 | ========================= 3 | 4 | 5 | See https://powa.readthedocs.io/ 6 | 7 | [![Documentation Status](https://readthedocs.org/projects/powa/badge/?version=latest)](https://powa.readthedocs.io/en/latest/?badge=latest) 8 | 9 | 10 | Compile the doc 11 | ----------------------------------- 12 | 13 | * Install Sphinx: ``pip install -r requirements.txt`` 14 | 15 | * Build: ``make html`` 16 | 17 | * Or serve (live-reloaded): ``make serve`` 18 | -------------------------------------------------------------------------------- /docs/architecture.rst: -------------------------------------------------------------------------------- 1 | .. _architecture: 2 | 3 | PoWA architecture 4 | ================= 5 | 6 | Presentation 7 | ############ 8 | 9 | PoWA is a tool that relies on multiple components. Its main purpose is to 10 | gather metrics for multiple datasources, store them in a central repository and 11 | provide a UI to present those data in a way that makes it easy to troubleshoot 12 | problems. 13 | 14 | The main components are: 15 | 16 | - :ref:`powa_archivist`, a PostgreSQL extension. It has 2 purposes: 17 | 18 | - storing the various metrics in an space efficient way and providing any 19 | additional related feature (retention...) 20 | - providing a consistent view of the metrics, hiding any incompatibility 21 | between different version of PostgreSQL or any other data source 22 | - :ref:`powa_web`, the dedicated UI 23 | - :ref:`powa_collector`, an optional daemon to fetch the metrics from multiple 24 | remote hosts in the **Remote mode** (see below) 25 | 26 | The main datasource is **pg_stat_statements**, an extension provided by 27 | PostgreSQL, which is mandatory. All other datasources are optional and can be 28 | added or removed dynamically depending on your needs. 29 | 30 | The PoWA project project itself provides some additional datasources, and some 31 | other external datasources are also supported. The datasources are referred in 32 | this documentation as :ref:`stat_extensions`. 33 | 34 | PoWA can also rely on additional extensions, called **support extensions**. 35 | Those can be optionally used by PoWA, as they add additional features, but they 36 | don't provide metrics and are therefore handled differently. At this time, 37 | the only support extension is :ref:`hypopg_doc`. 38 | 39 | All the used :ref:`stat_extensions` should be installed only once, in the 40 | dedicated powa database. In case of remote mode, the same apply for the remote 41 | nodes and the repository server. Note that each remote node can have different 42 | set of extensions installed, and the repository server should contain all the 43 | extensions that are used on at least one remote node. 44 | 45 | The support extensions have different requirements. You need to install 46 | :ref:`hypopg_doc` in every database where you want to use the features it 47 | provides. 48 | 49 | .. _local_vs_remote: 50 | 51 | Local vs Remote mode 52 | #################### 53 | 54 | PoWA can be setup in two different modes, depending on your needs: 55 | 56 | - **local mode**, or self-contained mode 57 | - **remote mode** 58 | 59 | Local mode 60 | ---------- 61 | 62 | The local mode was the only available mode before PoWA 4. In this mode, all 63 | metrics and performance data are collected locally, on the same postgres 64 | instance. It relies on a **background worker** to do collect the metrics. 65 | Note that enabling the **background worker** requires restarting the instance. 66 | This **background worker** will then be automatically managed by postgres 67 | (started and stopped by postgres itself). You can refer to the `background 68 | worker documentation `_ 69 | for more information. 70 | 71 | Here's a schema of how architecture looks like with the local mode: 72 | 73 | .. image:: /images/powa_4_local.svg 74 | :width: 800 75 | :alt: Local mode diagram 76 | 77 | This can be a bit simpler to setup, but it has two majors drawbacks: 78 | 79 | - it adds a non negligible performance cost, both when collecting data and 80 | when using the user interface 81 | - it's not possible to collect data on hot-standby read-only servers 82 | 83 | Note also that some feature are not be available with the **local mode** (usually 84 | anything that needs to be collected on a database different than the powa 85 | database). 86 | 87 | As a consequence, while we continue to maintain it the **local mode** is not 88 | recommended for general usage and we advise you to rely on the **remote mode**. 89 | 90 | Remote mode 91 | ----------- 92 | 93 | Here's a schema for the remote mode architecture: 94 | 95 | .. image:: /images/powa_4_remote.svg 96 | :width: 800 97 | :alt: Remote mode diagram 98 | 99 | As you can see, all metrics and performance data are now stored on an external 100 | server, usually a dedicated server, that we call the **repository server**. 101 | The monitored server(s) are called the **remote server**, and you can setup as 102 | many as you want. 103 | 104 | The drawbacks mentioned in the local mode don't exist anymore: 105 | 106 | - all overhead of metrics storage and requests goes to the dedicated Powa 107 | repository server (except for the optional index suggestion and EXPLAIN 108 | plan which always go to the target remote server) 109 | - you can monitor a physical replication hot-standby server, even though it's 110 | read only 111 | 112 | Metrics on all the **remote servers** are collected using a new dedicated 113 | daemon: **powa-collector**. It replaces the **background worker**, which means 114 | that restarting postgres is not necessary anymore to start collecting metric on 115 | a new instance. It however means that there's a new daemon that needs to be 116 | configured and started. 117 | -------------------------------------------------------------------------------- /docs/components/hypopg.rst: -------------------------------------------------------------------------------- 1 | .. _hypopg: https://github.com/HypoPG/hypopg/ 2 | 3 | .. _hypopg_doc: 4 | 5 | HypoPG 6 | ====== 7 | 8 | HypoPG is a stat extension, but it's a useful extension to take full advantage 9 | of all the PoWA features. 10 | 11 | HypoPG allows you to create hypothetical indexe. A hypothetical index is an 12 | index that doesn't exists on disk. It's therefore almost instant to create and 13 | doesn't add any IO cost, whether at creation time or at maintenance time. The 14 | goal is obviously to check if an index is useful before spending too much time, 15 | I/O and disk space to create it. 16 | 17 | With this extension, you can create hypothetical indexes, and then with EXPLAIN 18 | check if PostgreSQL would use them or not. 19 | 20 | 21 | Where is it used in powa-web ? 22 | ****************************** 23 | 24 | If :ref:`pg_qualstats` is configured, PoWA will be able to detect missing 25 | indexes, either per-query or for the **whole workkload of a database**! 26 | 27 | When PoWA shows suggestion of missing indexes, if HypoPG is available **on the 28 | target database** (of the **remote server** if the :ref:`remote_setup` mode is 29 | used), it'll also try to create a hypothetical index for each suggested index, 30 | and show you if PostgreSQL would use it or not. 31 | 32 | This can be seen on the per-query page, in the **Predicates** tab: 33 | 34 | .. image:: ../images/hypopg_query.png 35 | :width: 800 36 | :alt: HypoPG example in the predicate tab 37 | 38 | And on the database page, if you use the "Optimize this database" feature: 39 | 40 | .. image:: ../images/hypopg_db.png 41 | :width: 800 42 | :alt: Global workload optimization example 43 | 44 | Installation 45 | ************ 46 | 47 | As seen in :ref:`quickstart`, the PostgreSQL development packages should be 48 | available. 49 | 50 | First, you need to download and extract the lastest release of hypopg_. 51 | 52 | .. parsed-literal:: 53 | 54 | wget |hypopg_download_link| -O hypopg-|hypopg_release|.tar.gz 55 | tar zxvf hypopg-|hypopg_release|.tar.gz 56 | cd hypopg-|hypopg_release| 57 | 58 | Then, compile the extension: 59 | 60 | .. code-block:: bash 61 | 62 | make 63 | 64 | Then install the compiled file. This step has to be made with the user that has 65 | installed PostgreSQL. If you have used a package, it will be certainly be root. 66 | If so: 67 | 68 | .. code-block:: bash 69 | 70 | sudo make install 71 | 72 | Else, sudo into the user that owns your PostgreSQL executables, and 73 | 74 | .. code-block:: bash 75 | 76 | make install 77 | 78 | No specific configuration or PostgreSQL restart is needed. 79 | 80 | Connect as a superuser on each database of each server you want to be able to 81 | use hypopg_ on, and type: 82 | 83 | .. code-block:: sql 84 | 85 | CREATE EXTENSION hypopg ; 86 | 87 | See Also 88 | ******** 89 | 90 | * :ref:`pg_qualstats` 91 | * `Official documentation `_ 92 | -------------------------------------------------------------------------------- /docs/components/index.rst: -------------------------------------------------------------------------------- 1 | .. _components: 2 | 3 | Components 4 | ========== 5 | 6 | This sections gathers the various components and external extensions that PoWA 7 | can use. 8 | 9 | .. toctree:: 10 | :maxdepth: 2 11 | 12 | introduction 13 | powa-archivist/index 14 | powa-collector/index 15 | powa-web/index 16 | stats_extensions/index 17 | hypopg 18 | 19 | -------------------------------------------------------------------------------- /docs/components/introduction.rst: -------------------------------------------------------------------------------- 1 | .. _components_intro: 2 | 3 | Introduction to the PoWA components 4 | =================================== 5 | 6 | PoWA is a highly extensible tool. PostgreSQL needs and usage vary for 7 | everyone, so not a single set of metrics is ideal for all usecases. In order 8 | to provide the best experience for everyone, all the metrics (or datasources) 9 | can be configured to suits your specific needs, choosing the one you want or do 10 | not want and even adding your own. 11 | 12 | Different kind of metrics 13 | ------------------------- 14 | 15 | PoWA supports 3 kind of metrics, that each correspond to a different way of 16 | retrieving data from your instance: 17 | 18 | - **stat extensions**: those provide the most useful and low-level information, 19 | and require installing extensions, either from the contrib or from the list 20 | of community provided extensions. 21 | - **modules**: those provide access to instance wide catalog information 22 | - **database modules**: those provide access to database-local catalog 23 | information 24 | 25 | The definition and configuration for all those metrics are stored in powa 26 | catalogs, and can be enabled or disabled at any time, and can even be 27 | dynamically extended with user-defined information so that PoWA retrieves your 28 | specific data, without any modification to PoWA itself. 29 | 30 | The list of known components, whether they're enabled or not and the rest of 31 | the associated details is available in the powa-web UI, in the **configuration 32 | page** for each remote server. 33 | 34 | Stat extensions 35 | --------------- 36 | 37 | Those are the most wildly used components, as they can provide really useful 38 | and low level performance information. They usually store metrics on all the 39 | databases in shared memory, and expose all the counters from a place. The most 40 | famous stat extension (and the only mandatory one) is 41 | :ref:`pg_stat_statements_doc`, but a lot more are supported. You can find the 42 | list of supported stat extensions at :ref:`stat_extensions`. 43 | 44 | If you wrote you own extension, and want to retrieves metrics for another 45 | extension that isn't supported, you can look at :ref:`integration_with_powa` 46 | documentation for more details. 47 | 48 | They are available in either the **local mode** or the **remote mode** (see the 49 | :ref:`local_vs_remote` page for more details). 50 | 51 | Modules 52 | ------- 53 | 54 | Those are a bit similar to the stat extensions. They provide access to 55 | information that is not specific to a single database but for either all of 56 | them, or the instance itself. The main difference is that they are fully 57 | defined in plain SQL. 58 | 59 | Some example of modules are metrics for the **pg_stat_xxx** system views (e.g. 60 | **pg_stat_archiver**, **pg_stat_bgwriter** or **pg_stat_replication**). The 61 | shared catalog caching (**pg_database** and **pg_role**) also rely on this 62 | infrastructure. 63 | 64 | They are only available in the **remote mode** (see the :ref:`local_vs_remote` 65 | page for more details). 66 | 67 | Database modules 68 | ---------------- 69 | 70 | Those are mostly the same as plain modules, except that they can will be 71 | collected on the wanted subset of database(s) that you define. As a 72 | consequence, they can access database-local metrics that are not accessible for 73 | the other kind of metic source. They are also defined in plain SQL, and also 74 | have builtin support for multiple major PostgreSQL versions so that you can 75 | write different queries for the various major PostgreSQL version to ease 76 | backward compatibility. 77 | 78 | Some example of database modules are **pg_stat_all_indexes**, 79 | **pg_stat_all_tables** and **pg_stat_user_functions** system views. 80 | Database-local catalogs (e.g. **pg_class**, **pg_attribute**, ...) also rely on 81 | this infrastructure. 82 | 83 | They are only available in the **remote mode** (see the :ref:`local_vs_remote` 84 | page for more details). 85 | -------------------------------------------------------------------------------- /docs/components/powa-archivist/configuration.rst: -------------------------------------------------------------------------------- 1 | .. _powa-archivist-configuration: 2 | 3 | background worker configuration 4 | ******************************* 5 | 6 | .. note:: 7 | 8 | This is intended for local-mode setup. 9 | 10 | The following configuration parameters (GUCs) are available in 11 | ``postgresql.conf``: 12 | 13 | powa.frequency: 14 | Defaults to ``5min``. 15 | Defines the frequency of the snapshots, in milliseconds or any time unit supported by PostgreSQL. Minimum 5s. You can use the usual postgresql time abbreviations. If not specified, the unit is seconds. Setting it to -1 will disable powa (powa will still start, but it won't collect anything anymore, and wont connect to the database). 16 | powa.retention: 17 | Defaults to ``1d`` (1 day) 18 | Automatically purge data older than that. If not specified, the unit is minutes. 19 | powa.database: 20 | Defaults to ``powa`` 21 | Defines the database of the workload repository. 22 | powa.coalesce: 23 | Defaults to ``100``. 24 | Defines the amount of records to group together in the table. 25 | 26 | .. _powa_archivist_remote_servers_configuration: 27 | 28 | Remote servers configuration 29 | **************************** 30 | 31 | .. note:: 32 | 33 | This is intended for the :ref:`remote_setup` mode. 34 | 35 | You can declare, configure and remove *remote servers* using an SQL API. 36 | 37 | powa_register_server 38 | -------------------- 39 | 40 | This function declare a new remote server and the activated extensions. 41 | 42 | The arguments are: 43 | 44 | hostname (`text`): 45 | Mandatory, default `NULL`. 46 | Hostname or IP address of the remote PostgreSQL instance. 47 | port (`integer`) 48 | Mandatory, default `5432`. 49 | Port of the remote PostgreSQL instance. 50 | alias (`text`): 51 | Optional, default `NULL`. 52 | User-friendly alias of the remote PostgreSQL instance (needs to be unique). 53 | username (`text`): 54 | Mandatory, default `'powa'`. 55 | Username to user to connect on the remote PostgreSQL instance. 56 | password (`text`): 57 | Optional, default `NULL`. 58 | Password to user to connect on the remote PostgreSQL instance. If no password 59 | is provided, the connection can fallback on other standard authentication 60 | method (.pgpass file, certificate...) depending on how the remote server is 61 | configured. 62 | dbname (`text`): 63 | Mandatory, default `'powa'`. 64 | Database to connect on the remote PostgreSQL instance. 65 | frequency (`integer`): 66 | Mandatory, default `300`, 67 | Snapshot interval for the remote server, in seconds. 68 | retention (`interval`): 69 | Mandatory, default `'1 day'::interval`. 70 | Data retention for the remote server. 71 | powa_coalesce (`integer`): 72 | Optional, default `100`. 73 | Defines the amount of records to group together in the table for 74 | the corresponding remote server. 75 | allow_ui_connection (`boolean`): 76 | Mandatory, default `true`. 77 | Specify if the UI is allowed to connect to the remote server to access user 78 | objects. 79 | extensions (`text[]`): 80 | Optional, default `NULL`. 81 | List of extensions on the remote server for which the data should be stored. 82 | You don't need to specify :ref:`pg_stat_statements_doc`. As it's a mandatory 83 | extensions, it'll be automatically added. 84 | 85 | This function return **true** if the server was registered. 86 | 87 | .. note:: 88 | 89 | - The (hostname, port) must be unique. 90 | - This function will not try to connect on the remote server to validate 91 | that the list of extensions is correct. If you declared extensions that 92 | are not available or properly setup on the remote server, the underlying 93 | data won't be available and you'll see errors in the 94 | :ref:`powa_collector` logs and the :ref:`powa_web` user interface. 95 | 96 | .. warning:: 97 | 98 | Connection on the remote server can be attempted by the :ref:`powa_web` 99 | user interface and :ref:`powa_collector`. 100 | The connection for :ref:`powa_collector` **is mandatory**. The user 101 | interface can work without such remote connection, but with **limited 102 | features** (notably, index suggestion will not be available). 103 | 104 | You can call this function as any SQL function, using a **superuser**. 105 | 106 | For instance, to add a remote server on **myserver.domain.com**, with the alias 107 | **myserver**, with default port and database, the password **mypassword**, and 108 | **all the supported extensions**: 109 | 110 | Example: 111 | 112 | .. code-block:: sql 113 | 114 | SELECT powa_register_server(hostname => 'myserver.domain.com', 115 | alias => 'myserver', 116 | password => 'mypassword', 117 | extensions => '{pg_stat_kcache,pg_qualstats,pg_wait_sampling}'); 118 | 119 | powa_activate_extension 120 | ----------------------- 121 | 122 | This function is automatically called by `powa_register_server`. It can be 123 | useful if you setup an additional :ref:`stat_extensions` after the inital 124 | *remote server* declaration. 125 | 126 | The arguments are: 127 | 128 | _srvid (`integer`): 129 | Mandatory, default `NULL`. 130 | Interval serveur identifier. You can find the identifier in the 131 | `powa_servers` table, containing the list of remote instances. 132 | _extname (`text`): 133 | Mandatory, default `NULL`. 134 | The name of the extension to activate. 135 | 136 | This function return **true** if the extension was activated on the given 137 | *remote server*. 138 | 139 | Example: 140 | 141 | .. code-block:: sql 142 | 143 | SELECT powa_activate_extension(1, 'extension_name'); 144 | 145 | powa_deactivate_extension 146 | ------------------------- 147 | 148 | This function can be useful if you removed a :ref:`stat_extensions` after the 149 | inital *remote server* declaration. 150 | 151 | The arguments are: 152 | 153 | _srvid (`integer`): 154 | Mandatory, default `NULL`. 155 | Interval serveur identifier. You can find the identifier in the 156 | `powa_servers` table, containing the list of remote instances. 157 | _extname (`text`): 158 | Mandatory, default `NULL`. 159 | The name of the extension to deactivate. 160 | 161 | This function return **true** if the extension was deactivated on the given 162 | *remote server*. 163 | 164 | Example: 165 | 166 | .. code-block:: sql 167 | 168 | SELECT powa_deactivate_extension(1, 'extension_name'); 169 | 170 | powa_configure_server 171 | --------------------- 172 | 173 | This function can be useful if you want to change any of the *remote server* 174 | property after its inital declaration. 175 | 176 | The arguments are: 177 | 178 | _srvid (`integer`): 179 | Mandatory, default `NULL`. 180 | Interval serveur identifier. You can find the identifier in the 181 | `powa_servers` table, containing the list of remote instances. 182 | _data (`json`): 183 | Mandatory 184 | The changes you want to perform, provided as a JSON value where the key is 185 | the property to update and the value is the value to use. 186 | 187 | This function return **true** if the configuration was changed for the given 188 | *remote server*. 189 | 190 | Example: 191 | 192 | .. code-block:: sql 193 | 194 | SELECT powa_configure_server(1, '{"alias": "my new alias", "password": null}'); 195 | 196 | powa_deactivate_server 197 | ---------------------- 198 | 199 | This function can be useful if you want to disable snapshots on the specified 200 | *remote server*, but keep its stored data. 201 | 202 | The arguments are: 203 | 204 | _srvid (`integer`): 205 | Mandatory, default `NULL`. 206 | Interval serveur identifier. You can find the identifier in the 207 | `powa_servers` table, containing the list of remote instances. 208 | 209 | This function return **true** if the given *remote server* were deactivated. 210 | 211 | Example: 212 | 213 | .. code-block:: sql 214 | 215 | SELECT powa_deactivate_server(1); 216 | 217 | powa_delete_and_purge_server 218 | ---------------------------- 219 | 220 | This function can be useful if you want to delete a server from the list of 221 | *remote servers*, and delete any stored data related to it. 222 | 223 | The arguments are: 224 | 225 | _srvid (`integer`): 226 | Mandatory, default `NULL`. 227 | Interval serveur identifier. You can find the identifier in the 228 | `powa_servers` table, containing the list of remote instances. 229 | 230 | This function return **true** if the given *remote server* were deleted. 231 | 232 | Example: 233 | 234 | .. code-block:: sql 235 | 236 | SELECT powa_delete_and_purge_server(1); 237 | -------------------------------------------------------------------------------- /docs/components/powa-archivist/development.rst: -------------------------------------------------------------------------------- 1 | .. _integration_with_powa: 2 | 3 | Integrating another stat extension in Powa 4 | ========================================== 5 | 6 | Clone the repository: 7 | 8 | .. code:: bash 9 | 10 | git clone https://github.com/powa-team/powa-archivist/ 11 | cd powa-archivist/ 12 | make && sudo make install 13 | 14 | Any modification to the background-worker code will need a PostgreSQL restart. 15 | 16 | .. note:: 17 | 18 | With PoWA 4 and the :ref:`remote_setup` mode, modifications to the 19 | background worker are less likely to be required. 20 | 21 | 22 | In order to contribute another source of data, you will have to implement the 23 | following infrastructure. An exemple is provided for each required object, 24 | assuming a very naive datasource called `my_datasource`, that returns a single 25 | **integer** counter, called `my_counter`. 26 | 27 | You can see any of the supported datasource implementation to have a better 28 | idea of how to efficiently store, aggregate and purge data. 29 | 30 | Functions required for data snapshot 31 | ------------------------------------ 32 | 33 | 34 | **query_source(integer)**: 35 | This function is reponsible to provide either the data corresponding to the 36 | **local datasource** if called with `0`, or the data that have been stored in 37 | the **transient table** otherwise. 38 | 39 | .. code-block:: plpgsql 40 | 41 | CREATE OR REPLACE FUNCTION powa_my_datasource_src(srvid integer) 42 | RETURNS void AS $PROC$ 43 | BEGIN 44 | IF (srvid = 0) THEN 45 | RETURN QUERY SELECT now(), my_counter 46 | FROM my_datasource(); 47 | ELSE 48 | RETURN QUERY SELECT ts, my_counter 49 | FROM public.powa_my_datasource_src_tmp 50 | WHERE srvid = _srvid; 51 | END IF; 52 | END; 53 | $PROC$ language plpgsql; 54 | 55 | .. note:: 56 | 57 | This function is required for PoWA 4 for *remote snapshot*. 58 | 59 | **snapshot(integer)**: 60 | This function is responsible for taking a snapshot of the data source data, 61 | and store it somewhere. Usually, this is done in a staging table named 62 | **powa_my_datasource_history_current**. It will be called every 63 | `powa.frequency` seconds. 64 | The function signature looks like this: 65 | 66 | .. code-block:: plpgsql 67 | 68 | CREATE OR REPLACE FUNCTION powa_my_datasource_snapshot(srvid integer) 69 | RETURNS void AS $PROC$ 70 | BEGIN 71 | INSERT INTO public.powa_my_datasource_snapshot_table 72 | SELECT srvid, * 73 | FROM public.powa_my_datasource_src(srvid); 74 | END; 75 | $PROC$ language plpgsql; 76 | 77 | **aggregate(integer)**: 78 | This function will be called after every `powa.coalesce` number of snapshots. 79 | It is responsible for aggregating the current staging values into another 80 | table, to reduce the disk usage for PoWA. Usually, this will be done in an 81 | aggregation table named **powa_my_datasource_history**. 82 | The function signature looks like this: 83 | 84 | .. code-block:: plpgsql 85 | 86 | CREATE OR REPLACE FUNCTION powa_my_datasource_aggregate(srvid integer) 87 | RETURNS void AS $PROC$ 88 | ... 89 | $PROC$ language plpgsql; 90 | 91 | **purge(integer)**: 92 | This function will be called after every 10 aggregates and is responsible for 93 | purging stale data that should not be kept. The function should take the 94 | `powa.retention` global parameter into account to prevent removing data that 95 | would still be valid. 96 | 97 | .. code-block:: plpgsql 98 | 99 | CREATE OR REPLACE FUNCTION powa_my_datasource_aggregate(srvid integer) 100 | RETURNS void AS $PROC$ 101 | ... 102 | $PROC$ language plpgsql; 103 | 104 | **unregister(integer)**: 105 | This function will be called if the related extension is dropped. 106 | 107 | Please note that the **module** name used in the **powa_functions** table 108 | has to be the same as the extension name, otherwise this function will not be 109 | called. 110 | 111 | This function should at least remove entries from **powa_functions** table. 112 | A minimal function would look like this: 113 | 114 | .. code-block:: plpgsql 115 | 116 | CREATE OR REPLACE function public.powa_my_datasource_unregister(srvid integer) 117 | RETURNS bool AS 118 | $_$ 119 | BEGIN 120 | DELETE FROM public.powa_functions WHERE module = 'my_datasource'; 121 | RETURN true; 122 | END; 123 | $_$ 124 | language plpgsql; 125 | 126 | Optional functions for data snapshot 127 | ------------------------------------ 128 | 129 | **query_cleanup**: 130 | This can contain any SQL code, which will be executed as-is **for remote 131 | snapshot** by **powa-collector** just after the **query_source** function has 132 | been executed. The same code should normally be present in the *snapshot 133 | function* for *local snapshot*, when the passed `server id` is **0**. This 134 | is normally not required, but if for example you don't want to store 135 | cumulated data in each snapshot, this is the right place to reset the metrics 136 | your extension stores. You can refer to `pg_qualstats` integration for a 137 | usage example. 138 | 139 | .. warning:: 140 | 141 | This can't be used as a way to free any resources the **query_source** 142 | function could have allocated, as this function isn't guaranteed to be 143 | executed in some corner cases (error during **query_source** execution, 144 | fast shutdown of the collector...) 145 | 146 | .. warning:: 147 | 148 | You should obviously be very careful with what you store in this field, or 149 | who you allow to update the `powa_functions` table, as no verification is 150 | done on the content. 151 | 152 | Registering functions for data snapshot 153 | --------------------------------------- 154 | 155 | Each of these functions should then be registered: 156 | 157 | .. code-block:: sql 158 | 159 | INSERT INTO powa_functions (module, operation, function_name, query_source, added_manually) 160 | VALUES ('my_datasource', 'snapshot', 'powa_mydatasource_snapshot', 'powa_my_datasource_src', true), 161 | ('my_datasource', 'aggregate', 'powa_mydatasource_aggregate', NULL, true), 162 | ('my_datasource', 'unregister', 'powa_mydatasource_unregister', NULL, true), 163 | ('my_datasource', 'purge', 'powa_mydatasource_purge', NULL, true); 164 | 165 | Transient table required for data remote snapshot 166 | ------------------------------------------------- 167 | 168 | When :ref:`remote_setup` is used, data from the **source extensions** have to be 169 | exported from the *remote server* to the *repository server*. Each data source 170 | therefore require a *transient table* to store those exported data on the 171 | *repository server* until the *remote snapshot* is finished. 172 | 173 | The table must use this naming convention: 174 | 175 | **public.${snapshot_function_name}_tmp** 176 | 177 | For instance, if you're adding the **my_datasource** data source, and the 178 | snapshot function is name **powa_my_datasource_src(integer)**, the **transient 179 | table** has to be named: 180 | 181 | **public.powa_my_datasource_src_tmp** 182 | 183 | This table must have its first column declared as `srvid integer NOT NULL`. 184 | The rest of the column must match the output of the underlying **datasource 185 | function**. It's usually recommended to have this function also returns the 186 | timestamp when the data was acquired. 187 | 188 | For instance, if the **my_datasource** query source only returns a single 189 | *integer value*, the table would be declared like this: 190 | 191 | .. code-block:: plpgsql 192 | 193 | CREATE TABLE public.powa_my_datasource_src_tmp( 194 | srvid integer NOT NULL, 195 | ts timestamp with time zone NOT NULL, 196 | my_counter integer NOT NULL 197 | ); 198 | 199 | .. note:: 200 | 201 | The data stored in those table is only used, and valuable, while the 202 | snapshot is performed. So for performane reason, it's highly recommended 203 | to declare those tables as **unlogged**, as their data does not need to 204 | survive any incident. 205 | -------------------------------------------------------------------------------- /docs/components/powa-archivist/index.rst: -------------------------------------------------------------------------------- 1 | .. _powa_archivist: 2 | 3 | powa-archivist 4 | ============== 5 | 6 | .. toctree:: 7 | :maxdepth: 2 8 | 9 | installation.rst 10 | configuration.rst 11 | development.rst 12 | 13 | 14 | -------------------------------------------------------------------------------- /docs/components/powa-archivist/installation.rst: -------------------------------------------------------------------------------- 1 | .. _powa-archivist_installation: 2 | 3 | Installation 4 | ************ 5 | 6 | Introduction 7 | ------------ 8 | 9 | PoWA-archivist is the core component of the PoWA project. It is composed of 2 10 | elements: 11 | 12 | * an extension named "powa" containing management functions 13 | * a module name "powa" that optionally runs a background worker to collect the 14 | performance data on the local instance 15 | 16 | 17 | Prerequisites 18 | ------------- 19 | 20 | * PostgreSQL >= 9.4 21 | * PostgreSQL contrib modules (pg_stat_statements and btree_gist) 22 | * PostgreSQL server headers (if compiling from sources) 23 | 24 | Installation 25 | ------------ 26 | 27 | The recommended way to install PoWA-archivist is to use the packaged version 28 | available in the PGDG repositories, which available for GNU/Linux distributions 29 | based on Debian/Ubuntu or RHEL/Rocky/Fedora. If you're using a distribution 30 | where no PGDG repository or prepackaged version is available, we document 31 | installation from source code. 32 | 33 | Installation from PGDG repository 34 | ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ 35 | 36 | On Debian/Ubuntu, please refer to the `APT PGDG repository documentation 37 | ` for the initial setup (which should already be 38 | done if you have PostgreSQL installed), and simply install 39 | ``postgresql-XY-powa``. For instance, if you're using PostgreSQL 15: 40 | 41 | .. code-block:: bash 42 | 43 | sudo apt-get install postgresql-15-powa 44 | 45 | On RHEL/Rock/Fedora, please refer to the `YUM PGDG repository documentation 46 | ` for the iniial setup (which should already be 47 | done if you have PostgreSQL installed), and simply install 48 | ``powa_XY``. For instance, if you're using PostgreSQL 15: 49 | 50 | .. code-block:: bash 51 | 52 | sudo dnf install powa_15 53 | 54 | .. note:: 55 | 56 | Package names for older PostgreSQL version may vary and not contain an 57 | ``_`` between the package name and the PostgreSQL major version. 58 | 59 | Installation from sources 60 | ^^^^^^^^^^^^^^^^^^^^^^^^^ 61 | 62 | On Debian, the PostgreSQL server headers are installed via the 63 | ``postgresql-server-dev-XY`` package: 64 | 65 | .. code-block:: bash 66 | 67 | sudo apt-get install postgresql-server-dev-15 postgresql-contrib-15 68 | 69 | On RPM-based distros: 70 | 71 | .. code-block:: bash 72 | 73 | sudo dnf install postgresql15-devel postgresql15-contrib 74 | 75 | You also need a C compiler and other standard development tools. 76 | 77 | On Debian, these can be installed via the ``build-essential`` package: 78 | 79 | .. code-block:: bash 80 | 81 | apt-get install build-essential 82 | 83 | On RPM-based distros, the "Development Tools" can be used: 84 | 85 | .. code-block:: bash 86 | 87 | yum groupinstall "Development Tools" 88 | 89 | Grab the latest release, and install it: 90 | 91 | .. parsed-literal:: 92 | 93 | wget |download_link| -O powa-archivist-|rel_tag_name|.tar.gz 94 | tar zxvf powa-archivist-|rel_tag_name|.tar.gz 95 | cd powa-archivist-|rel_tag_name| 96 | 97 | 98 | Compile and install it: 99 | 100 | .. code-block:: bash 101 | 102 | make 103 | sudo make install 104 | 105 | .. note:: 106 | 107 | Make sure that ``sudo`` refers to the same PostgreSQL headers. Using 108 | ``pg_config`` and ``sudo pg_config`` should produce the same output. 109 | 110 | It should output something like the following : 111 | 112 | .. code-block:: bash 113 | 114 | /bin/mkdir -p '/usr/share/postgresql-15/extension' 115 | /bin/mkdir -p '/usr/share/postgresql-15/extension' 116 | /bin/mkdir -p '/usr/lib64/postgresql-15/lib64' 117 | /bin/mkdir -p '/usr/share/doc/postgresql-15/extension' 118 | /usr/bin/install -c -m 644 powa.control '/usr/share/postgresql-15/extension/' 119 | /usr/bin/install -c -m 644 powa--2.0.sql '/usr/share/postgresql-15/extension/' 120 | /usr/bin/install -c -m 644 README.md '/usr/share/doc/postgresql-15/extension/' 121 | /usr/bin/install -c -m 755 powa.so '/usr/lib64/postgresql-15/lib64/' 122 | 123 | PostgreSQL installation 124 | ----------------------- 125 | 126 | Create the PoWA database and create the required extensions, with the following 127 | statements: 128 | 129 | .. code-block:: sql 130 | 131 | CREATE EXTENSION pg_stat_statements; 132 | CREATE EXTENSION btree_gist; 133 | CREATE EXTENSION powa; 134 | 135 | 136 | Example: 137 | 138 | .. code-block:: bash 139 | 140 | bash-4.1$ psql 141 | psql (15.2) 142 | Type "help" for help. 143 | postgres=# create database powa; 144 | CREATE DATABASE 145 | postgres=# \c powa 146 | You are now connected to database "powa" as user "postgres". 147 | powa=# create extension pg_stat_statements ; 148 | CREATE EXTENSION 149 | powa=# create extension btree_gist ; 150 | CREATE EXTENSION 151 | powa=# create extension powa; 152 | CREATE EXTENSION 153 | 154 | As PoWA-archivist can provide a background worker, the library must be loaded 155 | at server start time if local metric collection is wanted. 156 | 157 | For this, modify the ``postgresql.conf`` configuration file, and add powa and 158 | pg_stat_statements to the ``shared_preload_libraries`` parameter: 159 | 160 | .. code-block:: ini 161 | 162 | shared_preload_libraries = 'pg_stat_statements,powa' 163 | 164 | If possible, activate ``track_io_timing`` too: 165 | 166 | 167 | .. code-block:: ini 168 | 169 | track_io_timing = on 170 | 171 | PostgreSQL should then be restarted. 172 | 173 | .. warning:: 174 | 175 | Since PoWA 4, you need to specify **powa** in the 176 | `shared_preload_libraries` configuration **ONLY** if you want to store the 177 | performance data locally. For remote storage, please see the 178 | :ref:`remote_setup` documentation. 179 | The :ref:`pg_stat_statements_doc` extension (as all other 180 | :ref:`stat_extensions`) still required to be configured in the 181 | `shared_preload_libraries` setting. 182 | 183 | If you're setting up a repository database for a remote server, you can 184 | also entirely skip the :ref:`pg_stat_statements_doc` configuration and the 185 | restart. 186 | 187 | Major PostgreSQL Upgrade 188 | ------------------------ 189 | 190 | .. warning:: 191 | 192 | There is a known issue with all PostgreSQL versions when using pg_upgrade 193 | on a instance having custom background workers, like PoWA in local setup 194 | mode: PostgreSQL doesn't prevent the background workers from doing their 195 | usual activity during pg_upgrade. It means that if the background worker 196 | performs some write when pg_upgrade expects that no write would happen, the 197 | resulting cluster can be corrupted. It's unfortunately not something that 198 | can be fixed from PoWA itself. 199 | 200 | If you want to perform a pg_upgrade of any instance having PoWA setup in 201 | local mode, you need to disable it before doing the pg_upgrade, and 202 | re-enable it once the upgrade is finished. 203 | -------------------------------------------------------------------------------- /docs/components/powa-collector/index.rst: -------------------------------------------------------------------------------- 1 | .. _powa_collector: 2 | 3 | powa-collector 4 | ============== 5 | 6 | .. _powa-collector-manual-installation: 7 | 8 | Install 9 | ************ 10 | 11 | You can install PoWA Collector either using `pip `_, RPM 12 | packages or manually. 13 | 14 | Install with pip 15 | -------------------- 16 | 17 | On Centos 6, you can avoid installing the header files for Python and 18 | PostgreSQL by using the package for psycopg2: 19 | 20 | 21 | .. code-block:: bash 22 | 23 | yum install python-pip python-psycopg2 24 | pip install powa-collector 25 | 26 | 27 | Install on Red Hat / CentOS / Fedora / Rocky Linux 28 | ----------------------------------------------------- 29 | 30 | The RPM package is available on the PostgreSQL YUM Repository. Follow the 31 | installation guidelines below to add this repository to your system: 32 | 33 | https://www.postgresql.org/download/linux/redhat/ 34 | 35 | Then install the package with: 36 | 37 | .. code-block:: bash 38 | 39 | yum install powa_collector 40 | 41 | 42 | Manual install 43 | -------------- 44 | 45 | You'll need the following dependencies: 46 | 47 | * `python 2.6, 2.7 or > 3 `_ 48 | * `psycopg2 `_ 49 | 50 | .. admonition:: debian 51 | 52 | .. code-block:: bash 53 | 54 | apt-get install python python-psycopg2 55 | 56 | 57 | .. admonition:: archlinux 58 | 59 | .. code-block:: bash 60 | 61 | pacman -S python python-psycopg2 62 | 63 | 64 | 65 | 66 | .. admonition:: fedora 67 | 68 | .. code-block:: bash 69 | 70 | TODO 71 | 72 | 73 | Then, download the latest release on `pypi 74 | `_, uncompress it, and copy the 75 | sample configuration file: 76 | 77 | .. parsed-literal:: 78 | 79 | wget |powa_collector_download_link| 80 | tar -zxvf powa-collector-|powa_collector_release|.tar.gz 81 | cd powa-collector-|powa_collector_release| 82 | cp ./powa-collector.conf-dist ./powa-collector.conf 83 | ./powa-collector 84 | 85 | Then, jump on the next section to configure powa-collector. 86 | 87 | 88 | Configuration 89 | ************* 90 | 91 | The powa-collector configuration is stored as a simple JSON file. 92 | Powa-collector will search its config as either of these files, in this order: 93 | 94 | * /etc/powa-collector.conf 95 | * ~/.config/powa-collector.conf 96 | * ~/.powa-collector.conf 97 | * ./powa-collector.conf 98 | 99 | The following options are required: 100 | 101 | repository.dsn (string): 102 | An URI to tell powa-collector how to connect on the dedicated repository powa 103 | database where to store data for all remote instances. 104 | 105 | The following options are optional: 106 | 107 | debug (boolean): 108 | A boolean to specify whether powa-collector should be launched in debug mode, 109 | providing a more verbose output, useful for debug purpose. 110 | 111 | 112 | Example configuration file: 113 | 114 | .. code-block:: python 115 | 116 | { 117 | "repository": { 118 | "dsn": "postgresql://powa_user@localhost:5432/powa" 119 | }, 120 | "debug": false 121 | } 122 | 123 | .. warning:: 124 | 125 | The collector needs to be able to connect on the **repository server** and 126 | all the declared **remote servers**. 127 | 128 | Usage 129 | ***** 130 | 131 | To start the program, simply run the powa-collector.py program. A ``SIGTERM`` 132 | or a ``Keyboard Interrupt`` on the program will cleanly stop all the thread and 133 | exit the program. A ``SIGHUP`` will reload the configuration. 134 | 135 | 136 | See also: 137 | 138 | .. toctree:: 139 | :maxdepth: 1 140 | 141 | protocol.rst 142 | -------------------------------------------------------------------------------- /docs/components/powa-collector/protocol.rst: -------------------------------------------------------------------------------- 1 | Protocol 2 | ======== 3 | 4 | A minimal communication protocol is implented, using the LISTEN/NOTIFY facility 5 | provided by postgres, which is used by the powa-web project. You can send 6 | queries to collector by sending messages on the "powa_collector" channel. The 7 | collector will send answers on the channel you specified, so make sure to 8 | listen on it before sending any query to not miss answers. 9 | 10 | The requests are of the following form: 11 | 12 | COMMAND RESPONSE_CHANNEL OPTIONAL_ARGUMENTS 13 | 14 | - COMMAND: mandatory argument describing the query. The following commands 15 | are supported: 16 | 17 | - RELOAD: reload the configuration and report that the main thread 18 | successfully received the command. The reload will be attempted even 19 | if no response channel was provided. 20 | 21 | - WORKERS_STATUS: return a JSON (srvid is the key, status is the content) 22 | describing the status of each remote server thread. Command is ignored 23 | if no response channel was provided. This command accept an optional 24 | argument to get the status of a single remote server, identified by its 25 | srvid. If no worker exists for this server, an empty JSON will be 26 | returned. 27 | 28 | - RESPONSE_CHANNEL: mandatory argument to describe the NOTIFY channel the 29 | client listens a response on. '-' can be used if no answer should be 30 | sent. 31 | 32 | - OPTIONAL_ARGUMENTS: space separated list of arguments, specific to the 33 | underlying command. 34 | 35 | The answers are of the form: 36 | 37 | COMMAND STATUS DATA 38 | 39 | - COMMAND: same as the command in the query 40 | 41 | - STATUS: OK or KO. 42 | 43 | - DATA: reason for the failure if status is KO, otherwise the data for the 44 | answer. 45 | 46 | -------------------------------------------------------------------------------- /docs/components/powa-web/deployment.rst: -------------------------------------------------------------------------------- 1 | Deployment Options 2 | ================== 3 | 4 | 5 | PoWA can be deployed easily using multiple methods. 6 | 7 | First you have to install and configure PoWA and `powa-web` like in the 8 | `quickstart` section. Check that the powa-web executable works before 9 | proceeding. 10 | 11 | Powa-web script 12 | --------------- 13 | 14 | The easiest option is to rely only on the provided `powa-web` script. You can 15 | configure it to serve HTTPS traffic, however it's not recommended to expose it 16 | directly but instead configure a reverse proxy like NGINX. 17 | 18 | When successfully started, you will find the address and port on which the UI 19 | is available on the standard output. The default is 0.0.0.0:8888, as indicated 20 | in this example message: 21 | 22 | .. code-block:: 23 | 24 | [I 161105 20:27:39 powa-web:12] Starting powa-web on https://0.0.0.0:8888 25 | 26 | NGINX 27 | ----- 28 | 29 | You can use NGINX as a reverse proxy to `powa-web`. It makes it possible to 30 | bind it to system ports (lower than 1024), and add HTTPS. 31 | 32 | Just add a new site to your configuration. Depending on your distribution, it 33 | will be somewhere like /etc/nginx/sites (RedHat derivatives), 34 | /etc/nginx/sites-available (Debian derivatives, you'll have to then do a 35 | symlink to /etc/nginx/sites-enabled to enable this site). 36 | 37 | Put this, for example, in the configuration file (if you just want HTTPS 38 | proxying, and no virtualhost): 39 | 40 | .. code-block:: nginx 41 | 42 | server { 43 | listen 0.0.0.0:443 http2 ssl default_server; 44 | server_name _; 45 | 46 | ssl_certificate /etc/pki/tls/certs/self-signed.pem; 47 | ssl_certificate_key /etc/pki/tls/certs/self-signed.key; 48 | 49 | access_log /var/log/nginx/access.log upstream; 50 | error_log /var/log/nginx/error.log; 51 | 52 | client_max_body_size 15M; 53 | 54 | location / { 55 | proxy_pass http://127.0.0.1:8888; 56 | } 57 | } 58 | 59 | You'll obviously need to produce certificates, which is out of scope of this 60 | documentation. 61 | 62 | If you just need HTTP, just change listen to 0.0.0.0:80, and remove ssl. 63 | Something like this: 64 | 65 | .. code-block:: nginx 66 | 67 | server { 68 | listen 0.0.0.0:80 http2 default_server; 69 | server_name _; 70 | 71 | ssl_certificate /etc/pki/tls/certs/self-signed.pem; 72 | ssl_certificate_key /etc/pki/tls/certs/self-signed.key; 73 | 74 | access_log /var/log/nginx/access.log upstream; 75 | error_log /var/log/nginx/error.log; 76 | 77 | client_max_body_size 15M; 78 | 79 | location / { 80 | proxy_pass http://127.0.0.1:8888; 81 | } 82 | } 83 | 84 | Apache 85 | ------ 86 | 87 | .. note:: 88 | 89 | The wsgi compatibility has been removed from tornado 6.1.0 and is not a 90 | recommended way to deploy powa-web anymore. 91 | 92 | PoWA can also easily be deployed using Apache mod_wsgi module. 93 | 94 | In your apache configuration file, you should: 95 | 96 | - load the mod_wsgi module 97 | - configure it. 98 | 99 | The various python3.4 version in the paths below should be set your actual 100 | python version: 101 | 102 | .. code-block:: apache 103 | 104 | LoadModule wsgi_module modules/mod_wsgi.so 105 | 106 | ServerName myserver.example.com 107 | 108 | DocumentRoot /var/www/ 109 | 110 | ErrorLog /var/log/httpd/powa.error.log 111 | CustomLog /var/log/httpd/powa.access.log combined 112 | 113 | WSGIScriptAlias / /usr/lib/python3.4/site-packages/powa/powa.wsgi 114 | 115 | Alias /static /usr/lib/python3.4/site-packages/powa/static/ 116 | 117 | -------------------------------------------------------------------------------- /docs/components/powa-web/development.rst: -------------------------------------------------------------------------------- 1 | Development 2 | =========== 3 | 4 | This page acts as a central hub for resources useful for PoWA developers. 5 | 6 | 7 | 8 | PoWA-Web 9 | -------- 10 | 11 | This section only covers the most simple changes one would want to make to PoWA. 12 | For more comprehensive documentation, see the Powa-Web project documentation 13 | itself. 14 | 15 | Clone the repository: 16 | 17 | .. code:: bash 18 | 19 | git clone https://github.com/powa-team/powa-web/ 20 | cd powa/ 21 | make && sudo make install 22 | 23 | To run the application, use run_powa.py, which will run powa in debug mode. 24 | That means the javascript files will not be minified, and will not be compiled 25 | into one giant source file. 26 | 27 | 28 | CSS files are generated using `sass `. 29 | Javascript files are splitted into AMD modules, which are managed by `requirejs 30 | ` and compiled using `grunt `. 31 | 32 | These projects depend on NodeJS, and NPM, its package manager, so make sure you are able to install them on your 33 | distribution. 34 | 35 | Install the development dependencies: 36 | 37 | .. code:: bash 38 | 39 | npm install -g grunt-cli 40 | npm install . 41 | 42 | Then, you can run ``grunt`` to update only the css files, or regenerate optimized 43 | javascript builds with ``grunt dist``. 44 | -------------------------------------------------------------------------------- /docs/components/powa-web/index.rst: -------------------------------------------------------------------------------- 1 | .. _powa_web: 2 | 3 | powa-web 4 | ======== 5 | 6 | .. toctree:: 7 | :maxdepth: 2 8 | 9 | installation.rst 10 | deployment.rst 11 | development.rst 12 | -------------------------------------------------------------------------------- /docs/components/powa-web/installation.rst: -------------------------------------------------------------------------------- 1 | .. _powa-web-manual-installation: 2 | 3 | Installation 4 | ************ 5 | 6 | Introduction 7 | ------------ 8 | 9 | PoWA-web is the dedicated user interface of the PoWA project. It produces 10 | graphs, grids and suggest various kind of optimisations based on the data 11 | stored on the PoWA repository server. 12 | 13 | Prerequisites 14 | ------------- 15 | 16 | * python >= 3.6 17 | * psycopg2 18 | * tornado >= 2.0 19 | 20 | Installation 21 | ------------ 22 | 23 | The recommended way to install **powa-web** is to use the packaged version 24 | available in the PGDG repositories for GNU/Linux distributions 25 | based on Debian/Ubuntu. 26 | 27 | For other platforms, or if you need a different version from the one provided 28 | by the PGDG repositories, you can either: 29 | 30 | * use the `provided container images 31 | `_, 32 | * install it from `pypi `_, 33 | * install it manually. 34 | 35 | We only document the package and manual installation here, as the other 36 | methods don't have anything specific step. 37 | 38 | Installation from Debian/Ubuntu PGDG repository 39 | *********************************************** 40 | 41 | Please refer to the `APT PGDG repository documentation 42 | ` for the initial setup (which should already be 43 | done if you have PostgreSQL installed), and simply install 44 | ``powa-web``. For instance: 45 | 46 | .. code-block:: bash 47 | 48 | sudo apt-get install powa-web 49 | 50 | Then, jump on the :ref:`next section` to configure powa-web. 51 | 52 | 53 | Manual installation 54 | ******************* 55 | 56 | You'll need the following dependencies: 57 | 58 | * `python >= 3.6 `_ 59 | * `psycopg2 `_ 60 | * `tornado >= 2.0 `_ 61 | 62 | .. tabs:: 63 | 64 | .. code-tab:: bash RHEL / Rocky 65 | 66 | # Enable the EPEL repository 67 | sudo dnf install -y epel-release 68 | crb enable 69 | 70 | # install the dependencies 71 | sudo dnf install -y python3 python3-psycopg2 python3-tornado 72 | 73 | .. code-tab:: bash Debian / Ubuntu 74 | 75 | sudo apt install -y python3 python3-psycopg2 python3-tornado 76 | 77 | .. code-tab:: bash Archlinux 78 | 79 | pacman -S python python-psycopg2 python-tornado 80 | 81 | 82 | Then, download the latest release on `pypi 83 | `_, uncompress it, and copy the sample 84 | configuration file: 85 | 86 | .. parsed-literal:: 87 | 88 | wget |powa_web_download_link| 89 | tar -zxvf powa-web-|powa_web_release|.tar.gz 90 | cd powa-web-|powa_web_release| 91 | cp ./powa-web.conf-dist ./powa-web.conf 92 | ./powa-web 93 | 94 | Then, jump on the :ref:`next section` to configure powa-web. 95 | 96 | .. _powa-web-config: 97 | 98 | Configuration 99 | ************* 100 | 101 | The powa-web configuration is stored as a simple python file. 102 | Powa-web will search its configuration in either of these files, in this order: 103 | 104 | * /etc/powa-web.conf 105 | * ~/.config/powa-web.conf 106 | * ~/.powa-web.conf 107 | * ./powa-web.conf 108 | 109 | You'll then be notified of the address and port on which the UI is available. 110 | The default is 0.0.0.0:8888, as indicated in this message: 111 | 112 | .. code-block:: 113 | 114 | [I 161105 20:27:39 powa-web:12] Starting powa-web on 0.0.0.0:8888 115 | 116 | The following options are required: 117 | 118 | servers (dict): 119 | A dictionary mapping PoWA repository server names to their connection 120 | information. 121 | 122 | .. code-block:: python 123 | 124 | servers={ 125 | 'main': { 126 | 'host': 'localhost', 127 | 'port': '5432', 128 | 'database': 'powa' 129 | } 130 | } 131 | 132 | .. warning:: 133 | 134 | If any of your databases is not in **utf8** encoding, you should specify a 135 | client_encoding option as shown below. This requires at least psycopg2 version 136 | 2.4.3 137 | 138 | .. code-block:: python 139 | 140 | servers={ 141 | 'main': { 142 | 'host': 'localhost', 143 | 'port': '5432', 144 | 'database': 'powa', 145 | 'query': {'client_encoding': 'utf8'} 146 | } 147 | } 148 | 149 | .. note:: 150 | 151 | You can set a username and password to allow logging into powa-web without 152 | providing credentials. In this case, the powa-web.conf file must be modified 153 | like this: 154 | 155 | .. code-block:: python 156 | 157 | servers={ 158 | 'main': { 159 | 'host': 'localhost', 160 | 'port': '5432', 161 | 'database': 'powa', 162 | 'username' : 'pg_username', 163 | 'password' : 'the password', 164 | 'query': {'client_encoding': 'utf8'} 165 | } 166 | } 167 | 168 | 169 | cookie_secret (str): 170 | A secret key used to secure cookies transiting between the web browser and the 171 | server. 172 | 173 | .. code-block:: python 174 | 175 | cookie_secret="SECRET_STRING" 176 | 177 | The following options are optional: 178 | 179 | port (int): 180 | The port on which the UI will be available (default 8888) 181 | 182 | 183 | address (str): 184 | The IP address on which the UI will be available (default 0.0.0.0) 185 | 186 | certfile (str): 187 | Path to certificate file, to allow HTTPS traffic (keyfile is also required) 188 | 189 | keyfile (str)/ 190 | Path to certificate private key file, to allow HTTPS traffic (certfile is 191 | also required) 192 | 193 | url_prefix (str): 194 | Custom URL prefix the UI should be available on 195 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/index.rst: -------------------------------------------------------------------------------- 1 | .. _stat_extensions: 2 | 3 | Stats Extensions 4 | ================ 5 | 6 | The PoWA-archivist collects data from various stats extensions. To be used in 7 | PoWA, a stat extensions has to expose a number of PL/pgSQL functions as stated 8 | in :ref:`integration_with_powa`. 9 | 10 | Currently, the list of supported stat extensions is as follows: 11 | 12 | .. toctree:: 13 | :maxdepth: 1 14 | 15 | pg_stat_statements.rst 16 | pg_qualstats.rst 17 | pg_stat_kcache.rst 18 | pg_wait_sampling.rst 19 | pg_track_settings.rst 20 | 21 | All those extensions have to be installed on the dedicated powa database of the 22 | monitored server. 23 | 24 | .. note:: 25 | 26 | pg_track_settings has to be also be installed on the dedicated repository 27 | server if :ref:`remote_setup` configuration is used. 28 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/pg_qualstats.rst: -------------------------------------------------------------------------------- 1 | .. _pg_qualstats: 2 | 3 | pg_qualstats 4 | ============ 5 | 6 | pg_qualstats is a PostgreSQL extension keeping statistics on predicates found 7 | in ```WHERE``` statements and ```JOIN``` clauses. 8 | 9 | The goal of this extension is to allow the DBA to answer some specific questions, whose answers are quite hard to come by: 10 | 11 | * what is the set of queries using this column ? 12 | * what are the values this where clause is most often using ? 13 | * do I have some significant skew in the distribution of the number of returned rows if use some value instead of one another ? 14 | * which columns are often used together in a WHERE clause ? 15 | 16 | Where is it used in powa-web ? 17 | ****************************** 18 | 19 | If the extension is available, you should see a "list of quals" table on the 20 | query page, as well as explain plans for your query and a list of index 21 | suggestions: 22 | 23 | .. image:: /images/pg_qualstats.png 24 | :width: 800 25 | :alt: pg_qualstats example 26 | 27 | From this list, you can then go on to the per-qual page. 28 | 29 | 30 | Installation 31 | ************ 32 | 33 | As seen in :ref:`quickstart`, the PostgreSQL development packages should be 34 | available. 35 | 36 | First, download and extract the latest release of pg_qualstats_: 37 | 38 | 39 | .. parsed-literal:: 40 | 41 | wget |pg_qualstats_download| -O pg_qualstats-|pg_qualstats_release|.tar.gz 42 | tar zxvf pg_qualstats-|pg_qualstats_release|.tar.gz 43 | cd pg_qualstats-|pg_qualstats_release| 44 | 45 | Then, compile the extension: 46 | 47 | .. code-block:: bash 48 | 49 | make 50 | 51 | Then install the compiled package: 52 | 53 | .. code-block:: bash 54 | 55 | make install 56 | 57 | Then you just have to declare the extension in the ``postgresql.conf`` file, like this : 58 | 59 | .. code-block:: ini 60 | 61 | shared_preload_libraries = 'pg_stat_statements,pg_qualstats' 62 | 63 | Restart the PostgreSQL server to reload the libraries. 64 | 65 | Connect to the server as a superuser and type: 66 | 67 | .. code-block:: sql 68 | 69 | CREATE EXTENSION pg_qualstats; 70 | 71 | Using with PoWA 72 | *************** 73 | 74 | If you want PoWA to handle this extension, you have to connect as a superuser 75 | on the database where you installed PoWA, and type: 76 | 77 | .. code-block:: sql 78 | 79 | SELECT powa_qualstats_register(); 80 | 81 | Configuration 82 | ************* 83 | 84 | The following configuration parameters are available, in postgresql.conf: 85 | 86 | pg_qualstats.enabled: 87 | Defaults to ``true``. 88 | Enable pg_qualstats. Can be useful if you want to enable / disable it without restarting the server. 89 | pg_qualstats.max: 90 | Defaults to ``1000``. 91 | Number of entries to keep. As a rule of thumb, you should keep at least ``pg_stat_statements.max`` entries if ``pg_qualstats.track_constants`` is disabled, else it should be roughly equal to the number of queries executed during ``powa.frequency`` interval of time. 92 | pg_qualstats.track_pg_catalog: 93 | Defaults to ``false``. 94 | Determine if predicates on pg_catalog tables should be tracked too. 95 | pg_qualstats.resolve_oids: 96 | Defaults to ``false``. 97 | Determine if during predicates collection, the actual name of the objects should be stored alongside their OIDs. The overhead is quite non-negligible, since each entry will occupy 616 bytes instead of 168. 98 | pg_qualstats.track_constants: 99 | Defaults to ``true``. 100 | If true, each new value for each predicate will result in a new entry. Eg, ``WHERE id = 3`` and ``WHERE id = 4`` will results in two entries in pg_qualstats. If disabled, only one entry for ``WHERE id = ?`` will be kept. Turning this off drastically reduces the number of entries to keep, at the price of not getting any hindsight on most frequently used values. 101 | pg_qualstats.sample_rate: 102 | (Used to be "sample_ratio") 103 | Defaults to ``-1``, which means ``1 / MAX_CONNECTIONS`` 104 | The ratio of queries that should be sampled. 1 means sample every single 105 | query, 0 basically deactivates the feature, and -1 is automatically sized to 106 | ``1/ MAX_CONNECTIONS``. For example, a sample_rate of ``0.1`` would mean one 107 | of out ten queries should be sampled. 108 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/pg_stat_kcache.rst: -------------------------------------------------------------------------------- 1 | .. _pg_stat_kcache: https://github.com/powa-team/pg_stat_kcache 2 | 3 | .. _pg_stat_kcache_doc: 4 | 5 | pg_stat_kcache 6 | ============== 7 | 8 | pg_stat_kcache_ is a PostgreSQL extension gathering statistics on system 9 | metrics. 10 | 11 | Thanks to this extension, the DBA can see how much resource each query, user 12 | and/or database is consuming. The resources are: 13 | 14 | * CPU (user time and system time) 15 | * Physical disk access (read and write) 16 | 17 | Physical disk access are essential in calculating a real hit ratio (cached_reads/all_reads). Without this, we only have the shared_buffers' hit ratio, and some of the reads made by Postgres could be served by the system cache. 18 | 19 | Where is it used in powa-web ? 20 | ****************************** 21 | 22 | If the extension is available, you should see "Physical block" and "CPU time" 23 | graphs on the query page: 24 | 25 | .. image:: /images/pg_stat_kcache_1.png 26 | :width: 800 27 | :alt: pg_stat_kcache physical disk usage example 28 | .. image:: /images/pg_stat_kcache_2.png 29 | :width: 800 30 | :alt: pg_stat_kcache CPU time usage example 31 | 32 | The **CPU time** metrics indicate the percentage of query runtime spent 33 | consuming either *user cpu time* or *system cpu time*. 34 | 35 | 36 | The "Hit ratio" graph will also handle this extension, displaying the following 37 | metrics : 38 | 39 | * **Shared buffers hit ratio**: percentage of blocks read from shared buffers (memory) 40 | * **System cache hit ratio**: precentage of blocks read from the system cache (memory) 41 | * **Disk hit ratio**: Percentage of blocks which needed a physical disk read 42 | 43 | The rest of the available metrics will be displayed on a dedicated **System 44 | Resources** graph: 45 | 46 | .. image:: /images/pg_stat_kcache_system_resources.png 47 | :width: 800 48 | :alt: pg_stat_kcache system resources example 49 | 50 | Installation 51 | ************ 52 | 53 | pg_stat_kcache_ should work with any POSIX operating system. Therefore, it 54 | won't on Windows. 55 | 56 | As seen in :ref:`quickstart`, the PostgreSQL development packages should be 57 | available. 58 | 59 | First, you need to download and extract the lastest release of pg_stat_kcache_. 60 | 61 | .. parsed-literal:: 62 | 63 | wget |pg_stat_kcache_download| -O pg_stat_kcache-|pg_stat_kcache_release|.tar.gz 64 | tar zxvf pg_stat_kcache-|pg_stat_kcache_release|.tar.gz 65 | cd pg_stat_kcache-|pg_stat_kcache_release| 66 | 67 | 68 | Then, compile the extension: 69 | 70 | .. code-block:: bash 71 | 72 | make 73 | 74 | If everything goes fine, you will have this kind of output : 75 | 76 | .. code-block:: bash 77 | 78 | gcc -O0 -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fexcess-precision=standard -g -fpic -I. -I./ -I/home/rjuju/postgres/pgs/postgresql-9.4.beta2/include/server -I/home/rjuju/postgres/pgs/postgresql-9.4.beta2/include/internal -D_GNU_SOURCE -I/usr/include/libxml2 -c -o pg_stat_kcache.o pg_stat_kcache.c 79 | gcc -O0 -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fexcess-precision=standard -g -fpic -shared -o pg_stat_kcache.so pg_stat_kcache.o -L/home/rjuju/postgres/pgs/postgresql-9.4.beta2/lib -L/usr/lib/x86_64-linux-gnu -Wl,--as-needed -Wl,-rpath,'/home/rjuju/postgres/pgs/postgresql-9.4.beta2/lib',--enable-new-dtags 80 | 81 | Then install the compiled file. This step has to be made with the user that has 82 | installed PostgreSQL. If you have used a package, it will be certainly be root. 83 | If so: 84 | 85 | .. code-block:: bash 86 | 87 | sudo make install 88 | 89 | Else, sudo into the user that owns your PostgreSQL executables, and 90 | 91 | .. code-block:: bash 92 | 93 | make install 94 | 95 | 96 | Then you just have to declare the extension in the ``postgresql.conf`` file, like this : 97 | 98 | .. code-block:: ini 99 | 100 | shared_preload_libraries = 'pg_stat_statements,pg_stat_kcache' 101 | 102 | Restart the PostgreSQL server to reload the libraries. 103 | 104 | Connect to the server as a superuser and type: 105 | 106 | .. code-block:: sql 107 | 108 | CREATE EXTENSION pg_stat_kcache ; 109 | 110 | Using with PoWA 111 | *************** 112 | 113 | If you want PoWA to handle this extension, you have to connect as a superuser 114 | on the database where you installed PoWA, and type: 115 | 116 | .. code-block:: sql 117 | 118 | SELECT powa_kcache_register(); 119 | 120 | Configuration 121 | ************* 122 | 123 | pg_stat_kcache_ will retain as many query statistic as pg_stat_statements, so 124 | there's nothing to configure. 125 | 126 | Examples 127 | ******** 128 | 129 | See Also 130 | ******** 131 | 132 | * :ref:`pg_stat_statements_doc` 133 | * :ref:`pg_qualstats` 134 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/pg_stat_statements.rst: -------------------------------------------------------------------------------- 1 | .. _pg_stat_statements: https://www.postgresql.org/docs/current/pgstatstatements.html 2 | 3 | .. _pg_stat_statements_doc: 4 | 5 | pg_stat_statements 6 | ================== 7 | 8 | The pg_stat_statements_ extension records statistics of all SQL queries (aka 9 | "statements") executed on a given PostgreSQL server. 10 | 11 | The statistics gathered are available in view called ``pg_stat_statements``. 12 | This view contains one row for each distinct database ID, user ID and query ID. 13 | However the number of distinct statements tracked cannot exceed a certain limit 14 | (5 000 by default) 15 | 16 | The pg_stat_statements_ extension is a key component of the PoWA Suite, 17 | installing it is **mandatory**. 18 | 19 | .. warning:: 20 | 21 | PoWA relies on the metrics being monotonic, so if you reset the metrics 22 | regularly (by calling `pg_stat_statements_reset()` explicitly or using a tool 23 | that calls this function), the various reports will be nonsensical. 24 | 25 | Where is it used in powa-web ? 26 | ****************************** 27 | 28 | The PoWA user interface (``powa-web``) relies heavily on pg_stat_statements_, 29 | so you'll see it used in almost every screen of the tool. 30 | 31 | The most useful feature is probably the "Query details" chart which show 32 | advanced statistics for each SQL query. 33 | 34 | .. image:: /images/pg_stat_statements.png 35 | :width: 800 36 | :alt: pg_stat_statements advanced statistics for a query 37 | 38 | 39 | Installation 40 | ************ 41 | 42 | pg_stat_statements_ is an official extension and it is released along with 43 | other extensions in the official PostgreSQL packages. 44 | You will find it in the ``contrib`` folder. Depending on which Operating 45 | System, you're using you may need to install a separate package to use it. For 46 | instance, on ``debian`` you may need to install the ``postgresql-contrib`` 47 | package. 48 | 49 | Then you just have to declare the extension in the ``postgresql.conf`` file, 50 | like this : 51 | 52 | ``shared_preload_libraries = 'pg_stat_statements'`` 53 | 54 | Restart the PostgreSQL server to reload the libraries. 55 | 56 | Connect to the server as a superuser and type: 57 | 58 | ``CREATE EXTENSION pg_stat_statements`` 59 | 60 | 61 | Configuration 62 | ************* 63 | 64 | There's a few parameters that you can add to the ``postgresql.conf``. For 65 | instance you can increase the track limit and allow PostgreSQL to record 10 000 66 | distinct queries: 67 | 68 | ``pg_stat_statements.max = 10000`` 69 | 70 | For more information about the pg_stat_statements_, please read the PostgreSQL 71 | documentation: 72 | 73 | https://www.postgresql.org/docs/current/pgstatstatements.html 74 | 75 | Examples 76 | ******** 77 | 78 | .. image:: /images/example_pgss.gif 79 | :width: 800 80 | :alt: pg_stat_statements manual usage example 81 | 82 | See Also 83 | ******** 84 | 85 | * https://www.craigkerstiens.com/2013/01/10/more-on-postgres-performance/ 86 | 87 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/pg_track_settings.rst: -------------------------------------------------------------------------------- 1 | .. _pg_track_settings: https://github.com/rjuju/pg_track_settings/ 2 | 3 | .. _pg_track_settings_doc: 4 | 5 | pg_track_settings 6 | ================= 7 | 8 | The pg_track_settings_ extension is a small SQL-only extension. Its purpose is 9 | to keep track of configuration changes happening on your instances. You can 10 | see more details of how to use this extension on a `presentation article 11 | `_. 12 | 13 | This extension will record any change happening in 14 | 15 | - the main configuration settings (as configured in *postgresql.conf* or with 16 | *ALTER SYSTEM* for instance), as reported by the **pg_settings** view. 17 | - the per-user and/or per-database settings (*ALTER ROLE ... SET*, *ALTER 18 | DATABASE ... SET* and *ALTER ROLE ... IN DATABASE SET*), as reported by the 19 | **pg_db_role_setting** table 20 | - PostgreSQL restart, using the **pg_postmaster_start_time()** function 21 | 22 | when the **snapshot function** is called (or the **functions** starting from 23 | version 2.0.0). 24 | 25 | .. note:: 26 | 27 | If the user running the snapshot function has a per-user and/or a 28 | per-database settings, this setting will "hide" the regular value 29 | in *pg_setting*, so keep this restriction in mind when investigatin the 30 | extension reports. 31 | 32 | All versions are compatible with PoWA with the standalone setup. Since version 33 | 2.0.0, pg_track_settings_ is compatible with the :ref:`remote_setup` added in 34 | PoWA 4. 35 | 36 | 37 | Where is it used in powa-web ? 38 | ****************************** 39 | 40 | If the extension is properly configured, you should see a timeline widget, 41 | placed between each graph and its overview, displaying any kind of recorded 42 | change if any was detected in the currently selected time interval. This list 43 | will be filtered by the database currently displayed if the current page is 44 | displaying a specific database. This timeline will be displayed on every graph 45 | of the page, to easily check if this change had any visible impact. 46 | 47 | Details of the changes will be displayed on mouseover, along with a vertical 48 | line to show exactly when the change happened. 49 | 50 | .. image:: /images/pg_track_settings.png 51 | :width: 800 52 | :alt: pg_track_settings example 53 | 54 | 55 | Installation 56 | ************ 57 | 58 | As seen in :ref:`quickstart`, the PostgreSQL development packages should be 59 | available. 60 | 61 | First, download and extract the latest release of pg_track_settings_: 62 | 63 | 64 | .. parsed-literal:: 65 | 66 | wget |pg_track_settings_download| -O pg_track_settings-|pg_track_settings_release|.tar.gz 67 | tar zxvf pg_track_settings-|pg_track_settings_release|.tar.gz 68 | cd pg_track_settings-|pg_track_settings_release| 69 | 70 | Since it's an SQL-only extension, there's no need to compile anything. You 71 | just need to install the package: 72 | 73 | .. code-block:: bash 74 | 75 | make install 76 | 77 | No specific configuration or PostgreSQL restart is needed. Simply connect on 78 | the PoWA database as a superuser and type: 79 | 80 | .. code-block:: sql 81 | 82 | CREATE EXTENSION pg_track_settings; 83 | 84 | .. note:: 85 | 86 | If you're installing a :ref:`remote_setup` configuration, then you need **at 87 | least the version 2.0.0** of the extension. It also has to be intalled: 88 | 89 | - on the dedicated powa database of the **repository server** 90 | - on the dedicated powa database of all the **remote servers** for which 91 | you want to track the configuration changes 92 | 93 | Using with PoWA 94 | *************** 95 | 96 | If you want PoWA to handle this extension, you have to connect as a superuser 97 | on the database where you installed PoWA, and type: 98 | 99 | .. code-block:: sql 100 | 101 | SELECT powa_track_settings_register(); 102 | -------------------------------------------------------------------------------- /docs/components/stats_extensions/pg_wait_sampling.rst: -------------------------------------------------------------------------------- 1 | .. _pg_wait_sampling: https://github.com/postgrespro/pg_wait_sampling/ 2 | .. _wait_events: https://www.postgresql.org/docs/current/monitoring-stats.html#WAIT-EVENT-TABLE 3 | .. _PostgresProfessional: https://github.com/postgrespro/ 4 | 5 | .. _pg_wait_sampling_doc: 6 | 7 | pg_wait_sampling 8 | ================ 9 | 10 | The pg_wait_sampling_ extension is devlopped by PostgresProfessional_. It 11 | samples wait_events_ of all SQL queries executed on a given PostgreSQL server, 12 | providing **waits profile**, an accumulated view of wait events. 13 | 14 | The **waits profile** is available in view called ``pg_wait_sampling_profile``. 15 | This view contains one row for each distinct Process ID, wait event type, event 16 | and query ID. 17 | 18 | 19 | Where is it used in powa-web ? 20 | ****************************** 21 | 22 | If the extension is available, you should see a "Wait events for all databases" 23 | table on the overview page and a "Wait events for all queries" table on the 24 | database page. Those tables report the list of reported wait events for the given 25 | period, either on the overall instance or on the database only. 26 | 27 | .. image:: /images/powa_waits_overview.png 28 | :width: 800 29 | :alt: pg_wait_sampling on all databases example 30 | .. image:: /images/powa_waits_db.png 31 | :width: 800 32 | :alt: pg_wait_sampling for a single databases example 33 | 34 | On the query page, a "Wait Events" tab is available, where you'll see both a 35 | graph of reported wait events, per type, and a table of all reported wait 36 | events, both for the given period. 37 | 38 | .. image:: /images/powa_waits_query.png 39 | :width: 800 40 | :alt: pg_wait_sampling for a single query example 41 | 42 | 43 | Installation 44 | ************ 45 | 46 | As seen in :ref:`quickstart`, the PostgreSQL development packages should be 47 | available. 48 | 49 | First, download and extract the latest release of pg_wait_sampling_: 50 | 51 | 52 | .. parsed-literal:: 53 | 54 | wget |pg_wait_sampling_download| -O pg_wait_sampling-|pg_wait_sampling_release|.tar.gz 55 | tar zxvf pg_wait_sampling-|pg_wait_sampling_release|.tar.gz 56 | cd pg_wait_sampling-|pg_wait_sampling_release| 57 | 58 | Then, compile the extension: 59 | 60 | .. code-block:: bash 61 | 62 | make USE_PGXS=1 63 | 64 | Then install the compiled package: 65 | 66 | .. code-block:: bash 67 | 68 | make USE_PGXS=1 install 69 | 70 | Then you just have to declare the extension in the ``postgresql.conf`` file, like this : 71 | 72 | .. code-block:: ini 73 | 74 | shared_preload_libraries = 'pg_stat_statements,pg_wait_sampling' 75 | 76 | Restart the PostgreSQL server to reload the libraries. 77 | 78 | Connect to the server as a superuser and type: 79 | 80 | .. code-block:: sql 81 | 82 | CREATE EXTENSION pg_wait_sampling; 83 | 84 | Using with PoWA 85 | *************** 86 | 87 | If you want PoWA to handle this extension, you have to connect as a superuser 88 | on the database where you installed PoWA, and type: 89 | 90 | .. code-block:: sql 91 | 92 | SELECT powa_wait_sampling_register(); 93 | 94 | Configuration 95 | ************* 96 | 97 | For a complete description of the confirugration parameters, please refer to 98 | the official pg_wait_sampling_ documentation. 99 | 100 | For PoWA needs, here are the important settings: 101 | 102 | pg_wait_sampling.profile_period: 103 | Defaults to ``10``. 104 | Period for profile sampling in milliseconds. 105 | 106 | pg_wait_sampling.profile_pid: 107 | Defaults to ``true``. 108 | Whether profile should be per pid. **Should be set to false for PoWA usage**. 109 | true will work, but consume resources needlessly. 110 | 111 | pg_wait_sampling.profile_queries: 112 | Defaults to ``true``. 113 | Whether profile should be per normalized query, as provided by 114 | :ref:`pg_stat_statements_doc` extension. **Should be set to true for PoWA 115 | usage**. 116 | 117 | See Also 118 | ******** 119 | 120 | * `List of wait events in PostgreSQL `_ 121 | -------------------------------------------------------------------------------- /docs/conf.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python3 2 | # -*- coding: utf-8 -*- 3 | # 4 | # PoWA documentation build configuration file, created by 5 | # sphinx-quickstart on Fri Feb 6 09:40:18 2015. 6 | # 7 | # This file is execfile()d with the current directory set to its 8 | # containing dir. 9 | # 10 | # Note that not all possible configuration values are present in this 11 | # autogenerated file. 12 | # 13 | # All configuration values have a default; values that are commented out 14 | # serve to show the default. 15 | 16 | import sys 17 | import os 18 | 19 | sys.path.insert(0, ".") 20 | 21 | # If extensions (or modules to document with autodoc) are in another directory, 22 | # add these directories to sys.path here. If the directory is relative to the 23 | # documentation root, use os.path.abspath to make it absolute, like shown here. 24 | #sys.path.insert(0, os.path.abspath('.')) 25 | 26 | # -- General configuration ------------------------------------------------ 27 | 28 | # If your documentation needs a minimal Sphinx version, state it here. 29 | #needs_sphinx = '1.0' 30 | 31 | # Add any Sphinx extension module names here, as strings. They can be 32 | # extensions coming with Sphinx (named 'sphinx.ext.*') or your custom 33 | # ones. 34 | extensions = [ 35 | 'sphinx.ext.intersphinx', 36 | 'sphinx.ext.todo', 37 | 'sphinx_tabs.tabs', 38 | ] 39 | 40 | image_config = { 41 | "override_image_directive": True 42 | } 43 | 44 | 45 | # Add any paths that contain templates here, relative to this directory. 46 | templates_path = ['_templates'] 47 | 48 | # The suffix of source filenames. 49 | source_suffix = '.rst' 50 | 51 | # The encoding of source files. 52 | #source_encoding = 'utf-8-sig' 53 | 54 | # The master toctree document. 55 | master_doc = 'index' 56 | 57 | # General information about the project. 58 | project = 'PoWA' 59 | copyright = '2014-2017, Dalibo - 2018-2024, The PoWA-team' 60 | 61 | # The version info for the project you're documenting, acts as replacement for 62 | # |version| and |release|, also used in various other places throughout the 63 | # built documents. 64 | # 65 | # The short X.Y version. 66 | version = '5.0' 67 | # The full version, including alpha/beta/rc tags. 68 | release = '5.0.0' 69 | powa_archivist_release = release 70 | hypopg_release = '1.3.1' 71 | powa_collector_release = '1.3.0' 72 | powa_web_release = '5.0.0' 73 | pg_qualstats_release = '2.1.1' 74 | pg_stat_kcache_release = 'REL2_3_0' 75 | pg_wait_sampling_release = 'v1.1.6' 76 | pg_track_settings_release = '2.1.2' 77 | 78 | 79 | # The language for content autogenerated by Sphinx. Refer to documentation 80 | # for a list of supported languages. 81 | #language = None 82 | 83 | # There are two options for replacing |today|: either, you set today to some 84 | # non-false value, then it is used: 85 | #today = '' 86 | # Else, today_fmt is used as the format for a strftime call. 87 | #today_fmt = '%B %d, %Y' 88 | 89 | # List of patterns, relative to source directory, that match files and 90 | # directories to ignore when looking for source files. 91 | exclude_patterns = ['_build'] 92 | 93 | # The reST default role (used for this markup: `text`) to use for all 94 | # documents. 95 | #default_role = None 96 | 97 | # If true, '()' will be appended to :func: etc. cross-reference text. 98 | #add_function_parentheses = True 99 | 100 | # If true, the current module name will be prepended to all description 101 | # unit titles (such as .. function::). 102 | #add_module_names = True 103 | 104 | # If true, sectionauthor and moduleauthor directives will be shown in the 105 | # output. They are ignored by default. 106 | #show_authors = False 107 | 108 | # The name of the Pygments (syntax highlighting) style to use. 109 | pygments_style = 'sphinx' 110 | 111 | # A list of ignored prefixes for module index sorting. 112 | #modindex_common_prefix = [] 113 | 114 | # If true, keep warnings as "system message" paragraphs in the built documents. 115 | #keep_warnings = False 116 | 117 | 118 | # -- Options for HTML output ---------------------------------------------- 119 | 120 | import sphinx_rtd_theme 121 | html_theme = 'sphinx_rtd_theme' 122 | html_theme_path = [sphinx_rtd_theme.get_html_theme_path()] 123 | 124 | # otherwise, readthedocs.io uses their theme by default, so no need to specify it 125 | 126 | 127 | # The theme to use for HTML and HTML Help pages. See the documentation for 128 | # a list of builtin themes. 129 | #html_theme = 'default' 130 | 131 | # Theme options are theme-specific and customize the look and feel of a theme 132 | # further. For a list of options available for each theme, see the 133 | # documentation. 134 | #html_theme_options = {} 135 | 136 | # Add any paths that contain custom themes here, relative to this directory. 137 | #html_theme_path = [] 138 | 139 | # The name for this set of Sphinx documents. If None, it defaults to 140 | # " v documentation". 141 | #html_title = None 142 | 143 | # A shorter title for the navigation bar. Default is the same as html_title. 144 | #html_short_title = None 145 | 146 | # The name of an image file (relative to this directory) to place at the top 147 | # of the sidebar. 148 | #html_logo = None 149 | 150 | # The name of an image file (within the static path) to use as favicon of the 151 | # docs. This file should be a Windows icon file (.ico) being 16x16 or 32x32 152 | # pixels large. 153 | #html_favicon = None 154 | 155 | # Add any paths that contain custom static files (such as style sheets) here, 156 | # relative to this directory. They are copied after the builtin static files, 157 | # so a file named "default.css" will overwrite the builtin "default.css". 158 | html_static_path = ['_static'] 159 | 160 | # Add any extra paths that contain custom files (such as robots.txt or 161 | # .htaccess) here, relative to this directory. These files are copied 162 | # directly to the root of the documentation. 163 | #html_extra_path = [] 164 | 165 | # If not '', a 'Last updated on:' timestamp is inserted at every page bottom, 166 | # using the given strftime format. 167 | #html_last_updated_fmt = '%b %d, %Y' 168 | 169 | # If true, SmartyPants will be used to convert quotes and dashes to 170 | # typographically correct entities. 171 | #html_use_smartypants = True 172 | 173 | # Custom sidebar templates, maps document names to template names. 174 | #html_sidebars = {} 175 | 176 | # Additional templates that should be rendered to pages, maps page names to 177 | # template names. 178 | #html_additional_pages = {} 179 | 180 | # If false, no module index is generated. 181 | #html_domain_indices = True 182 | 183 | # If false, no index is generated. 184 | #html_use_index = True 185 | 186 | # If true, the index is split into individual pages for each letter. 187 | #html_split_index = False 188 | 189 | # If true, links to the reST sources are added to the pages. 190 | #html_show_sourcelink = True 191 | 192 | # If true, "Created using Sphinx" is shown in the HTML footer. Default is True. 193 | #html_show_sphinx = True 194 | 195 | # If true, "(C) Copyright ..." is shown in the HTML footer. Default is True. 196 | #html_show_copyright = True 197 | 198 | # If true, an OpenSearch description file will be output, and all pages will 199 | # contain a tag referring to it. The value of this option must be the 200 | # base URL from which the finished HTML is served. 201 | #html_use_opensearch = '' 202 | 203 | # This is the file name suffix for HTML files (e.g. ".xhtml"). 204 | #html_file_suffix = None 205 | 206 | # Output file base name for HTML help builder. 207 | htmlhelp_basename = 'PoWAdoc' 208 | 209 | 210 | # -- Options for LaTeX output --------------------------------------------- 211 | 212 | latex_elements = { 213 | # The paper size ('letterpaper' or 'a4paper'). 214 | #'papersize': 'letterpaper', 215 | 216 | # The font size ('10pt', '11pt' or '12pt'). 217 | #'pointsize': '10pt', 218 | 219 | # Additional stuff for the LaTeX preamble. 220 | #'preamble': '', 221 | } 222 | 223 | # Grouping the document tree into LaTeX files. List of tuples 224 | # (source start file, target name, title, 225 | # author, documentclass [howto, manual, or own class]). 226 | latex_documents = [ 227 | ('index', 'PoWA.tex', 'PoWA Documentation', 228 | 'The PoWA-team', 'manual'), 229 | ] 230 | 231 | # The name of an image file (relative to this directory) to place at the top of 232 | # the title page. 233 | #latex_logo = None 234 | 235 | # For "manual" documents, if this is true, then toplevel headings are parts, 236 | # not chapters. 237 | #latex_use_parts = False 238 | 239 | # If true, show page references after internal links. 240 | #latex_show_pagerefs = False 241 | 242 | # If true, show URL addresses after external links. 243 | #latex_show_urls = False 244 | 245 | # Documents to append as an appendix to all manuals. 246 | #latex_appendices = [] 247 | 248 | # If false, no module index is generated. 249 | #latex_domain_indices = True 250 | 251 | 252 | # -- Options for manual page output --------------------------------------- 253 | 254 | # One entry per manual page. List of tuples 255 | # (source start file, name, description, authors, manual section). 256 | man_pages = [ 257 | ('index', 'powa', 'PoWA Documentation', 258 | ['The PoWA-team'], 1) 259 | ] 260 | 261 | # If true, show URL addresses after external links. 262 | #man_show_urls = False 263 | 264 | 265 | # -- Options for Texinfo output ------------------------------------------- 266 | 267 | # Grouping the document tree into Texinfo files. List of tuples 268 | # (source start file, target name, title, author, 269 | # dir menu entry, description, category) 270 | texinfo_documents = [ 271 | ('index', 'PoWA', 'PoWA Documentation', 272 | 'The PoWA-team', 'PoWA', 'One line description of project.', 273 | 'Miscellaneous'), 274 | ] 275 | 276 | # Documents to append as an appendix to all manuals. 277 | #texinfo_appendices = [] 278 | 279 | # If false, no module index is generated. 280 | #texinfo_domain_indices = True 281 | 282 | # How to display URL addresses: 'footnote', 'no', or 'inline'. 283 | #texinfo_show_urls = 'footnote' 284 | 285 | # If true, do not generate a @detailmenu in the "Top" node's menu. 286 | #texinfo_no_detailmenu = False 287 | 288 | 289 | # Example configuration for intersphinx: refer to the Python standard library. 290 | 291 | rst_epilog = """ 292 | .. |download_link| replace:: https://github.com/powa-team/powa-archivist/archive/REL_{tagname}.tar.gz 293 | .. |rel_tag_name| replace:: REL_{tagname} 294 | .. |pg_stat_kcache_download| replace:: https://github.com/powa-team/pg_stat_kcache/archive/{pg_stat_kcache_release}.tar.gz 295 | .. |pg_stat_kcache_release| replace:: {pg_stat_kcache_release} 296 | .. |pg_wait_sampling_download| replace:: https://github.com/postgrespro/pg_wait_sampling/archive/{pg_wait_sampling_release}.tar.gz 297 | .. |pg_wait_sampling_release| replace:: {pg_wait_sampling_release} 298 | .. |pg_track_settings_download| replace:: https://github.com/rjuju/pg_track_settings/archive/{pg_track_settings_release}.tar.gz 299 | .. |pg_track_settings_release| replace:: {pg_track_settings_release} 300 | .. |powa_web_release| replace:: {powa_web_release} 301 | .. |powa_web_download_link| replace:: https://pypi.io/packages/source/p/powa-web/powa-web-{powa_web_release}.tar.gz 302 | .. |pg_qualstats_download| replace:: https://github.com/powa-team/pg_qualstats/archive/{pg_qualstats_release}.tar.gz 303 | .. |pg_qualstats_release| replace:: {pg_qualstats_release} 304 | .. |hypopg_release| replace:: {hypopg_release} 305 | .. |hypopg_download_link| replace:: https://github.com/hypopg/hypopg/archive/{hypopg_release}.tar.gz 306 | .. |powa_collector_release| replace:: {powa_collector_release} 307 | .. |powa_collector_download_link| replace:: https://pypi.io/packages/source/p/powa-collector/powa-collector-{powa_collector_release}.tar.gz 308 | 309 | """.format(**{ 310 | "tagname": "_".join(release.split('.')), 311 | "powa_web_release": powa_web_release, 312 | "pg_qualstats_release": pg_qualstats_release, 313 | "pg_stat_kcache_release": pg_stat_kcache_release, 314 | "pg_wait_sampling_release": pg_wait_sampling_release, 315 | "pg_track_settings_release": pg_track_settings_release, 316 | "powa-archivist_release": powa_archivist_release, 317 | "hypopg_release": hypopg_release, 318 | "powa_collector_release": powa_collector_release 319 | }) 320 | 321 | intersphinx_mapping = {'python': ('https://docs.python.org/3', None)} 322 | -------------------------------------------------------------------------------- /docs/contributing.rst: -------------------------------------------------------------------------------- 1 | Contributing 2 | ============ 3 | 4 | POWA is an open project available under the PostgreSQL License. Any 5 | contribution to build a better tool is welcome. 6 | 7 | 8 | Talk 9 | ---- 10 | 11 | If you have ideas or feature requests, please post them to our general bug 12 | tracker: https://github.com/powa-team/powa/issues 13 | 14 | You can also join the **#powa** IRC channel on the `IRC libera server 15 | `_. 16 | 17 | Test 18 | ---- 19 | 20 | If you've found a bug, please refer to :ref:`support` page to see how to report 21 | it. 22 | 23 | Code 24 | ---- 25 | 26 | PoWA is composed of multiples tools: 27 | 28 | * a background worker, see :ref:`powa_archivist` 29 | * a collector daemon, see :ref:`powa_collector` 30 | * stats extensions, see :ref:`stat_extensions` 31 | * a UI, see :ref:`powa_web` 32 | * external extensions: 33 | 34 | * :ref:`hypopg_doc` 35 | * :ref:`pg_wait_sampling_doc` 36 | * :ref:`pg_track_settings_doc` 37 | -------------------------------------------------------------------------------- /docs/debugging.rst: -------------------------------------------------------------------------------- 1 | .. _powa-archivist-from-the-sources: 2 | 3 | Unsupported OS and alternative use cases 4 | ======================================== 5 | 6 | In some cases you may want or need to rely on compiling one of various 7 | components of PoWA. For instance if you want to contribute a feature, need to 8 | test a specific bugfix or if you're using a operating system where no packages 9 | are available. 10 | 11 | This section gives a short introduction on the various container images: 12 | 13 | - `released version of 14 | PoWA <#released-versions-for-distro-where-no-packages-are-available>`_ 15 | - `git version of PoWA <#git-versions-of-powa>`_ 16 | - `PoWA development-oriented images <#development-oriented-images>`_ 17 | 18 | And how to compile the various components from source or rely on the various 19 | container images that we provide. 20 | 21 | Using the container images 22 | ************************** 23 | 24 | .. warning:: 25 | 26 | We **strongly** recomment you to follow the previous section and install the 27 | various packages from the PGDG repositories. 28 | This section is only meant as a documentation of the available container 29 | images, which are not recommended for production usage. 30 | 31 | The `powa-podman `_ repository 32 | contains various container images (and compose files) that can be used for 33 | various purposes. We assume here that you are familiar enough with **podman** 34 | or any alternative container management tool build the images and deploy them, 35 | and will only describe the various images provided. 36 | 37 | Released versions for distro where no packages are available 38 | ------------------------------------------------------------ 39 | 40 | The `powa-archivist directory 41 | `_ 42 | contains a Containerfile per supported major PostgreSQL version. It contains 43 | all the extensions (see the :ref:`components` section for the full 44 | list) supported by PoWA. Those images can be used as-is for either a 45 | repository or remote server in case of a :ref:`remote_setup` or a standalone 46 | installation. 47 | 48 | Then a **powa-web** user interface image can also be built using the files 49 | under the `powa-web directory 50 | `_. 51 | 52 | Finally, in case of a :ref:`remote_setup`, you will also need to run the 53 | :ref:`powa_collector` daemon. A container file is available for that in the 54 | `powa-collector directory 55 | `_. 56 | 57 | Additionally, the `compose directory 58 | `_ contains a few 59 | compose files that can be used to setup a fully working environment in either 60 | the **local mode** or the **remote mode** (see the :ref:`architecture page for 61 | more details page`). Those are only provided as reference and 62 | are not intended for production use. Feel free to adapt them to you own need 63 | instead. 64 | 65 | GIT versions of PoWA 66 | -------------------- 67 | 68 | The `powa-podman repository 69 | `_ provides 3 directories 70 | suffixed with **-git**: 71 | 72 | - powa-archivist-git 73 | - powa-web-git 74 | - powa-collector-git 75 | 76 | They provide the same components as the ones described in the previous section, 77 | but instead of providing a specific version of the underlying tools, they 78 | provide the current development version as-is. This can be useful to test a 79 | bugfix that hasn't been released yet. The exact version that those images 80 | provide depends on the time that they were built. If you want to ensure that 81 | you get the latest upstream commit, you should build them locally. 82 | 83 | Development-oriented images 84 | --------------------------- 85 | 86 | Finally, the `dev directory 87 | `_ contain images and 88 | compose files that are intended to help working on either the **powa-web** or 89 | the **powa-collector** project without manually setting up a fully working 90 | environment. The idea is that the various compose file will setup the 91 | environment, but using a **bind-mount** of the local version of the 92 | **powa-web** and **powa-collector** tools, so that any change made to them can 93 | be tested very easily. Please refer to the `documentation 94 | `_ for more 95 | details about it. 96 | 97 | Compile and install PoWA related extensions from the sources 98 | ************************************************************ 99 | 100 | .. warning:: 101 | 102 | We **strongly** recomment you to follow the previous section and install the 103 | various packages from the PGDG repositories. 104 | This section is only meant as a documentation of how to compile the various 105 | extensions for very specific needs, like testing a current development 106 | version, and is **NOT** the recommended way of installation. 107 | 108 | Prerequisites 109 | ------------- 110 | 111 | You will need a compiler, the appropriate PostgreSQL development packages, and 112 | some contrib modules. 113 | 114 | While on most installation, the contrib modules are installed with a 115 | postgresql-contrib package, if you wish to install them from source, you should 116 | note that only the following modules are required: 117 | 118 | * btree_gist 119 | * pg_stat_statements 120 | 121 | .. tabs:: 122 | 123 | .. code-tab:: bash RHEL / Rocky 124 | 125 | sudo dnf install postgresql14-devel postgresql14-contrib 126 | 127 | .. code-tab:: bash Debian / Ubuntu 128 | 129 | sudo apt install postgresql-server-dev-14 postgresql-contrib-14 130 | 131 | Installation 132 | ------------ 133 | 134 | Download powa-archivist latest release: 135 | 136 | .. parsed-literal:: 137 | wget |download_link| 138 | 139 | Convenience scripts are offered to build every project that PoWA can take 140 | advantage of. 141 | 142 | First, the install_all.sql file: 143 | 144 | .. code-block:: psql 145 | 146 | CREATE DATABASE IF NOT EXISTS powa; 147 | \c powa 148 | CREATE EXTENSION IF NOT EXISTS btree_gist; 149 | CREATE EXTENSION IF NOT EXISTS pg_stat_statements; 150 | CREATE EXTENSION IF NOT EXISTS pg_stat_kcache; 151 | CREATE EXTENSION IF NOT EXISTS pg_qualstats; 152 | CREATE EXTENSION IF NOT EXISTS pg_wait_sampling; 153 | CREATE EXTENSION IF NOT EXISTS pg_track_settings; 154 | CREATE EXTENSION IF NOT EXISTS powa; 155 | 156 | And the main build script: 157 | 158 | .. parsed-literal:: 159 | 160 | #!/bin/bash 161 | # This script is meant to install every PostgreSQL extension compatible with 162 | # PoWA. 163 | wget |pg_qualstats_download| -O pg_qualstats-|pg_qualstats_release|.tar.gz 164 | tar zxvf pg_qualstats-|pg_qualstats_release|.tar.gz 165 | cd pg_qualstats-|pg_qualstats_release| 166 | (make && sudo make install) > /dev/null 2>&1 167 | cd .. 168 | rm pg_qualstats-|pg_qualstats_release|.tar.gz 169 | rm pg_qualstats-|pg_qualstats_release| -rf 170 | wget |pg_stat_kcache_download| -O pg_stat_kcache-|pg_stat_kcache_release|.tar.gz 171 | tar zxvf pg_stat_kcache-|pg_stat_kcache_release|.tar.gz 172 | cd pg_stat_kcache-|pg_stat_kcache_release| 173 | (make && sudo make install) > /dev/null 2>&1 174 | cd .. 175 | rm pg_stat_kcache-|pg_stat_kcache_release|.tar.gz 176 | rm pg_stat_kcache-|pg_stat_kcache_release| -rf 177 | (make && sudo make install) > /dev/null 2>&1 178 | cd .. 179 | wget |pg_wait_sampling_download| -O pg_wait_sampling-|pg_wait_sampling_release|.tar.gz 180 | tar zxvf pg_wait_sampling-|pg_wait_sampling_release|.tar.gz 181 | cd pg_wait_sampling-|pg_wait_sampling_release| 182 | (make && sudo make install) > /dev/null 2>&1 183 | cd .. 184 | rm pg_wait_sampling-|pg_wait_sampling_release|.tar.gz 185 | rm pg_wait_sampling-|pg_wait_sampling_release| -rf 186 | wget |pg_track_settings_download| -O pg_track_settings-|pg_track_settings_release|.tar.gz 187 | tar zxvf pg_track_settings-|pg_track_settings_release|.tar.gz 188 | cd pg_track_settings-|pg_track_settings_release| 189 | (make && sudo make install) > /dev/null 2>&1 190 | cd .. 191 | rm pg_track_settings-|pg_track_settings_release|.tar.gz 192 | rm pg_track_settings-|pg_track_settings_release| -rf 193 | echo "" 194 | echo "You should add the following line to your postgresql.conf:" 195 | echo '' 196 | echo "shared_preload_libraries='pg_stat_statements,powa,pg_stat_kcache,pg_qualstats,pg_wait_sampling'" 197 | echo "" 198 | echo "Once done, restart your postgresql server and run the install_all.sql file" 199 | echo "with a superuser, for example: " 200 | echo " psql -U postgres -f install_all.sql" 201 | 202 | 203 | This script will ask for your super user password, provided the sudo command 204 | is available, and install powa, pg_qualstats, pg_stat_kcache and 205 | pg_wait_sampling for you. 206 | 207 | .. warning:: 208 | 209 | This script is not intended to be run on a production server, as it 210 | compiles all the extensions. You should prefer to install packages on your 211 | production servers. 212 | 213 | 214 | Once done, you should modify your PostgreSQL configuration as mentioned by the 215 | script, putting the following line in your `postgresql.conf` file: 216 | 217 | .. code-block:: ini 218 | 219 | shared_preload_libraries='pg_stat_statements,powa,pg_stat_kcache,pg_qualstats,pg_wait_sampling' 220 | 221 | Optionally, you can install the hypopg extension the same way from 222 | https://github.com/hypopg/hypopg/releases. 223 | 224 | And restart your server, according to your distribution's preferred way of doing 225 | so, for example: 226 | 227 | .. tabs:: 228 | 229 | .. code-tab:: bash RHEL / Rocky 230 | 231 | sudo systemctl restart postgresql 232 | 233 | .. code-tab:: bash Debian / Ubuntu 234 | 235 | sudo pg_ctlcluster 14 main restart 236 | 237 | The last step is to create a database dedicated to the PoWA repository, and 238 | create every extension in it. The install_all.sql file performs this task: 239 | 240 | .. code-block:: bash 241 | 242 | psql -U postgres -f install_all.sql 243 | CREATE DATABASE 244 | You are now connected to database "powa" as user "postgres". 245 | CREATE EXTENSION 246 | CREATE EXTENSION 247 | CREATE EXTENSION 248 | CREATE EXTENSION 249 | CREATE EXTENSION 250 | CREATE EXTENSION 251 | -------------------------------------------------------------------------------- /docs/images/example_pgss.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/example_pgss.gif -------------------------------------------------------------------------------- /docs/images/hypopg_db.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/hypopg_db.png -------------------------------------------------------------------------------- /docs/images/hypopg_query.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/hypopg_query.png -------------------------------------------------------------------------------- /docs/images/pg_qualstats.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_qualstats.png -------------------------------------------------------------------------------- /docs/images/pg_stat_kcache_1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_stat_kcache_1.png -------------------------------------------------------------------------------- /docs/images/pg_stat_kcache_2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_stat_kcache_2.png -------------------------------------------------------------------------------- /docs/images/pg_stat_kcache_system_resources.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_stat_kcache_system_resources.png -------------------------------------------------------------------------------- /docs/images/pg_stat_statements.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_stat_statements.png -------------------------------------------------------------------------------- /docs/images/pg_track_settings.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/pg_track_settings.png -------------------------------------------------------------------------------- /docs/images/powa_4_local.svg: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16 | 17 | 18 | 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | 120 | 121 | Background workerPowa 122 | 123 | 124 | 125 | 126 | 127 | 128 | 129 | 130 | 131 | Stats extensionspg_stat_statementspg_stat_kcachepg_qualstatspg_wait_samplingpg_track_settingspowa_archivist 132 | 133 | 134 | 135 | 136 | 137 | 138 | 139 | 140 | 141 | 142 | 143 | 144 | 145 | 146 | 147 | 148 | 149 | 150 | 151 | 152 | 153 | 154 | 155 | 156 | 157 | 158 | 159 | 160 | 161 | 162 | 163 | 164 | 165 | 166 | 167 | 168 | 169 | 170 | 171 | db2 172 | 173 | 174 | 175 | 176 | 177 | 178 | 179 | collect 180 | 181 | 182 | 183 | 184 | 185 | 186 | Powa web 187 | 188 | 189 | 190 | 191 | 192 | 193 | Postgres primary 194 | 195 | 196 | 197 | 198 | 199 | Powa db 200 | 201 | 202 | 203 | 204 | 205 | 206 | 207 | db1 208 | 209 | 210 | 211 | 212 | 213 | 214 | 215 | 216 | 217 | 218 | 219 | 220 | 221 | 222 | Fetch metrics 223 | 224 | 225 | 226 | 227 | 228 | 229 | 230 | 231 | 232 | 233 | 234 | 235 | 236 | 237 | EXPLAINIndex suggestion 238 | 239 | 240 | 241 | 242 | 243 | 244 | 245 | 246 | 247 | 248 | 249 | 250 | 251 | 252 | Snapshot storing 253 | 254 | 255 | 256 | 257 | 258 | 259 | 260 | -------------------------------------------------------------------------------- /docs/images/powa_4_remote.svg: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16 | 17 | 18 | 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | 120 | 121 | 122 | 123 | 124 | 125 | 126 | Powa extension 127 | 128 | 129 | 130 | 131 | 132 | 133 | 134 | 135 | 136 | 137 | 138 | 139 | 140 | 141 | Daemon PowaCollector 142 | 143 | 144 | 145 | 146 | 147 | 148 | 149 | db1 150 | 151 | 152 | 153 | 154 | 155 | 156 | Powa web 157 | 158 | 159 | 160 | 161 | 162 | 163 | Postgres primary – srvid 1 164 | 165 | 166 | 167 | 168 | 169 | 170 | 171 | 172 | 173 | 174 | 175 | 176 | 177 | 178 | 179 | 180 | 181 | 182 | 183 | 184 | 185 | 186 | 187 | 188 | 189 | 190 | Powa repository 191 | 192 | 193 | 194 | 195 | 196 | 197 | 198 | db2 199 | 200 | 201 | 202 | 203 | 204 | 205 | 206 | 207 | 208 | 209 | 210 | 211 | 212 | Server id 1Server id 2... 213 | 214 | 215 | 216 | 217 | 218 | 219 | 220 | EXPLAINIndex suggestion 221 | 222 | 223 | 224 | 225 | 226 | 227 | 228 | Stats extensionspg_stat_statementspg_stat_kcachepg_qualstatspg_wait_samplingpg_track_settingspowa_archivist 229 | 230 | 231 | 232 | 233 | 234 | 235 | 236 | 237 | 238 | 239 | 240 | 241 | 242 | 243 | 244 | 245 | 246 | 247 | 248 | 249 | 250 | 251 | 252 | 253 | 254 | 255 | 256 | 257 | 258 | 259 | 260 | 261 | 262 | 263 | 264 | 265 | 266 | Powa db 267 | 268 | 269 | 270 | 271 | 272 | 273 | 274 | 275 | 276 | 277 | 278 | 279 | Postgres standby – srvid 2 280 | 281 | 282 | 283 | 284 | 285 | 286 | 287 | db1 288 | 289 | 290 | 291 | 292 | 293 | 294 | 295 | db2 296 | 297 | 298 | 299 | 300 | 301 | 302 | 303 | Stats extensionspg_stat_statementspg_stat_kcachepg_qualstatspg_wait_samplingpg_track_settingspowa_archivist 304 | 305 | 306 | 307 | 308 | 309 | 310 | 311 | 312 | 313 | 314 | 315 | 316 | 317 | 318 | 319 | 320 | 321 | 322 | 323 | 324 | 325 | 326 | 327 | 328 | 329 | 330 | 331 | 332 | 333 | 334 | 335 | 336 | 337 | 338 | 339 | 340 | 341 | Powa db 342 | 343 | 344 | 345 | 346 | 347 | Powa 348 | 349 | 350 | 351 | 352 | 353 | 354 | 355 | 356 | 357 | 358 | 359 | 360 | 361 | 362 | 363 | 364 | 365 | 366 | 367 | 368 | 369 | collect 370 | 371 | 372 | 373 | 374 | 375 | 376 | 377 | 378 | 379 | 380 | 381 | 382 | 383 | 384 | Snapshot storing 385 | 386 | 387 | 388 | 389 | 390 | 391 | 392 | Fetch metrics 393 | 394 | 395 | 396 | 397 | 398 | 399 | 400 | StreamingReplication 401 | 402 | 403 | 404 | 405 | 406 | 407 | 408 | -------------------------------------------------------------------------------- /docs/images/powa_waits_db.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/powa_waits_db.png -------------------------------------------------------------------------------- /docs/images/powa_waits_overview.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/powa_waits_overview.png -------------------------------------------------------------------------------- /docs/images/powa_waits_query.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/docs/images/powa_waits_query.png -------------------------------------------------------------------------------- /docs/impact_on_perf.rst: -------------------------------------------------------------------------------- 1 | Impact on performances 2 | ====================== 3 | 4 | Using PoWA can have a small negative impact on your PostgreSQL server 5 | performances. It is hard to evaluate precisely this impact, as it can come from 6 | different parts. 7 | 8 | First of all, you need to activate at least `pg_stat_statements 9 | `_ 10 | extension, and possibly the other supported :ref:`stat_extensions` of your choice. 11 | Those extensions can slow down your instance, depending on how you 12 | configure them. 13 | 14 | If you don't use the :ref:`remote_setup` mode, the data will be stored locally 15 | on a regular basis. Depending on the snapshot frequency, the overhead could be 16 | important. You also have to consider disk usage, which will impact at least 17 | the backups. 18 | 19 | Using the UI will also run queries on your databases. With the 20 | :ref:`remote_setup` mode, there should be very few queries run on the target 21 | databases though. 22 | -------------------------------------------------------------------------------- /docs/index.rst: -------------------------------------------------------------------------------- 1 | .. title:: PostgreSQL Workload Analyzer 2 | 3 | |PostgreSQL Workload Analyzer| 4 | ================================= 5 | 6 | .. |PostgreSQL Workload Analyzer| image:: ../img/powa_logo.410x161.png 7 | :alt: PostgreSQL Workload Analyzer 8 | 9 | .. note:: 10 | 11 | You can try powa at demo-powa.anayrat.info_. Just click "Login" and 12 | try its features! Note that in order to get interesting metrics, resources 13 | have been limited on this server (2 vCPU, 384MB of RAM and 150iops for the 14 | disks). Please be patient when using it. 15 | 16 | Thanks to `Adrien Nayrat `_ for providing it. 17 | 18 | PoWA (PostgreSQL Workload Analyzer) is a performance tool compatible with **all 19 | PostgreSQL versions** (down to 9.4) allowing to collect, aggregate and purge 20 | statistics gathered from multiple PostgreSQL instances from various 21 | :ref:`stat_extensions`. 22 | 23 | Depending on your needs, you can choose one of different approaches to setup 24 | powa. 25 | 26 | For most people, the preferred approach is to use the provided 27 | :ref:`powa_collector` daemon to collect the metrics from one or multiple 28 | **remote** servers, and store them on a single (and usually dedicated) 29 | **repository** server. This is called the "remote mode", It does not require 30 | any PostgreSQL restart, and can gather performance metrics from multiple 31 | instances - including standby server. 32 | 33 | The other approach is called the "local mode". It's a self-contained solution 34 | that relies on a provided and optional `background worker`_, which requires a 35 | PostgreSQL restart to enable it, and more suited for a single-instance setup 36 | only. 37 | 38 | In both cases, PoWA will include support for various **stat extensions**: 39 | 40 | * :ref:`pg_stat_statements_doc`, providing data about queries being executed 41 | * :ref:`pg_qualstats`, providing data about predicates, or where clauses 42 | * :ref:`pg_stat_kcache_doc`, providing data about operating-system level cache 43 | * :ref:`pg_wait_sampling_doc`, providing data about wait events 44 | * :ref:`pg_track_settings_doc`, providing data about configuration changes and 45 | server restarts 46 | 47 | It also supports the following extension: 48 | 49 | * :ref:`hypopg_doc`, allowing you to create hypothetical indexes and test their 50 | usefulness without creating the real index 51 | 52 | Additionally, the PoWA User Interface allows you to make the most of this 53 | information. 54 | 55 | .. note:: 56 | 57 | **pg_stat_statements** is the main extension and is the basis for all the 58 | reports. It's the only extension that's not optional. PoWA also relies on 59 | the metrics being monotonic, so if you reset the metrics regularly (by 60 | calling `pg_stat_statements_reset()` explicitly or using a tool that calls 61 | this function), the various reports will be nonsensical. 62 | 63 | Main components 64 | *************** 65 | 66 | * :ref:`powa_archivist` is the PostgreSQL extension, collecting statistics. 67 | * :ref:`powa_collector` is the daemon that gather performance metrics from remote 68 | PostgreSQL instances (optional) on a dedicated repository server. 69 | * :ref:`powa_web` is the graphical user interface to powa-collected metrics. 70 | * the :ref:`stat_extensions` are the actual source of data. 71 | * **PoWA** is the whole project. 72 | 73 | You should first take a look at the :ref:`quickstart` guide, which covers the 74 | installation and configuration for the "local mode". You can then look at the 75 | :ref:`remote_setup` guide, which covers the necessary additional steps for a 76 | "remote mode" setup. 77 | 78 | 79 | .. toctree:: 80 | :maxdepth: 1 81 | 82 | architecture 83 | quickstart 84 | remote_setup 85 | FAQ 86 | security 87 | components/index 88 | impact_on_perf 89 | support 90 | releases 91 | contributing 92 | debugging 93 | 94 | .. _pg_stat_statements: https://www.postgresql.org/docs/current/pgstatstatements.html 95 | .. _pg_qualstats: https://github.com/powa-team/pg_qualstats 96 | .. _pg_stat_kcache: https://github.com/powa-team/pg_stat_kcache 97 | .. _background worker: https://www.postgresql.org/docs/current/bgworker.html 98 | .. _demo-powa.anayrat.info: https://demo-powa.anayrat.info/ 99 | -------------------------------------------------------------------------------- /docs/make.bat: -------------------------------------------------------------------------------- 1 | @ECHO OFF 2 | 3 | pushd %~dp0 4 | 5 | REM Command file for Sphinx documentation 6 | 7 | if "%SPHINXBUILD%" == "" ( 8 | set SPHINXBUILD=sphinx-build 9 | ) 10 | set SOURCEDIR=. 11 | set BUILDDIR=_build 12 | 13 | %SPHINXBUILD% >NUL 2>NUL 14 | if errorlevel 9009 ( 15 | echo. 16 | echo.The 'sphinx-build' command was not found. Make sure you have Sphinx 17 | echo.installed, then set the SPHINXBUILD environment variable to point 18 | echo.to the full path of the 'sphinx-build' executable. Alternatively you 19 | echo.may add the Sphinx directory to PATH. 20 | echo. 21 | echo.If you don't have Sphinx installed, grab it from 22 | echo.https://www.sphinx-doc.org/ 23 | exit /b 1 24 | ) 25 | 26 | if "%1" == "" goto help 27 | 28 | %SPHINXBUILD% -M %1 %SOURCEDIR% %BUILDDIR% %SPHINXOPTS% %O% 29 | goto end 30 | 31 | :help 32 | %SPHINXBUILD% -M help %SOURCEDIR% %BUILDDIR% %SPHINXOPTS% %O% 33 | 34 | :end 35 | popd 36 | -------------------------------------------------------------------------------- /docs/quickstart.rst: -------------------------------------------------------------------------------- 1 | .. _quickstart: 2 | 3 | Quickstart 4 | ========== 5 | 6 | .. warning:: 7 | 8 | The current version of PoWA is designed for PostgreSQL 9.4 and newer. If you 9 | want to use PoWA on PostgreSQL < 9.4, please use the `1.x series 10 | `_ 11 | 12 | The following describes the installation of the two main modules of PoWA: 13 | * powa-archivist (and all other supported extensions) using the PGDG packages 14 | (Red Hat/Rocky Linux, Debian/Ubuntu) 15 | * powa-web from the PGDG packages (Red Hat/CentOS/Rocky Linux, Debian/Ubuntu) 16 | or with python pip 17 | 18 | .. note:: 19 | 20 | This page shows how to configure a **local PoWA setup**. If you're 21 | interested in configuring PoWA for **multiple servers**, and/or for 22 | **standby servers**, please also refer to the :ref:`remote_setup` page to 23 | see additional steps for such a remote setup. 24 | 25 | 26 | Install PoWA related packages 27 | ***************************** 28 | 29 | Prerequirements 30 | --------------- 31 | 32 | PoWA must be installed on the PostgreSQL instance that you are monitoring. 33 | 34 | .. note:: 35 | 36 | All extensions except **hypopg** only need to be installed once, in the 37 | dedicated **powa** database (or another database name that you want to use). 38 | 39 | hypopg must be installed in every database on which you want to be able to 40 | get automatic index suggestion, including the powa database if needed. 41 | 42 | powa-web must be configured to connect on the database where you 43 | installed all the extensions. 44 | 45 | In these examples, you simply need to replace **14** according to your actual 46 | PostgreSQL major version (13, 10, 9.5...). 47 | 48 | What should be installed 49 | ------------------------ 50 | 51 | PoWA is a modular tool and let you choose which datasource(s) (backed by 52 | extensions) you want to add, depending on your needs. In the following 53 | examples we install all the supported extensions. You can skip any of them if 54 | you want, as long as you install the mandatory ones, which are: 55 | 56 | - pg_stat_statements 57 | - btree_gist 58 | - powa-archivist 59 | 60 | The PGDG package extension documentation also contain the necessary 61 | instructions to install and bootstrap a PostgreSQL instance. If you already 62 | have one you should skip this part and only use the documentation on how to add 63 | the additional extensions. 64 | 65 | Setup the PGDG repository and install the pacakges 66 | -------------------------------------------------- 67 | 68 | We suppose that you are using the packages from the PostgreSQL Development 69 | Group (https://yum.postgresql.org/ or https://apt.postgresql.org/). 70 | 71 | The following examples show how to install a PostgreSQL 14 cluster on Rocky 72 | Linux 8, following `the official YUM instructions 73 | `_, and any Debian / Ubuntu 74 | server, following `the official APT instructions 75 | `_: 76 | 77 | .. tabs:: 78 | 79 | .. code-tab:: bash RHEL / Rocky 80 | 81 | # Install the repository RPM: 82 | sudo dnf install -y https://download.postgresql.org/pub/repos/yum/reporpms/EL-8-x86_64/pgdg-redhat-repo-latest.noarch.rpm 83 | 84 | # Disable the built-in PostgreSQL module: 85 | sudo dnf -qy module disable postgresql 86 | 87 | # Install PostgreSQL: 88 | sudo dnf install -y postgresql14-server 89 | 90 | # Optionally initialize the database and enable automatic start: 91 | sudo /usr/pgsql-14/bin/postgresql-14-setup initdb 92 | sudo systemctl enable postgresql-14 93 | sudo systemctl start postgresql-14 94 | 95 | .. code-tab:: bash Debian / Ubuntu 96 | 97 | sudo apt install curl ca-certificates gnupg 98 | curl https://www.postgresql.org/media/keys/ACCC4CF8.asc | gpg --dearmor | sudo tee /etc/apt/trusted.gpg.d/apt.postgresql.org.gpg >/dev/null 99 | sudo sh -c 'echo "deb http://apt.postgresql.org/pub/repos/apt $(lsb_release -cs)-pgdg main" > /etc/apt/sources.list.d/pgdg.list' 100 | sudo apt update 101 | sudo apt install postgresql-14 postgresql-client-14 102 | 103 | You will also need the PostgreSQL contrib package to provide the 104 | **pg_stat_statements** extension: 105 | 106 | .. tabs:: 107 | 108 | .. code-tab:: bash RHEL / Rocky 109 | 110 | sudo dnf install postgresql14-contrib 111 | 112 | .. code-tab:: bash Debian / Ubuntu 113 | 114 | sudo apt install postgresql-contrib-14 115 | 116 | And the various powa extensions: 117 | 118 | .. tabs:: 119 | 120 | .. code-tab:: bash RHEL / Rocky 121 | 122 | sudo dnf install powa_14 pg_qualstats_14 pg_stat_kcache_14 hypopg_14 pg_wait_sampling_14 pg_track_settings_14 123 | 124 | .. code-tab:: bash Debian / Ubuntu 125 | 126 | apt-get install postgresql-14-powa postgresql-14-pg-qualstats postgresql-14-pg-stat-kcache postgresql-14-hypopg postgresql-14-pg-wait-sampling postgresql-14-pg-track-settings 127 | 128 | On other systems, or to test newer unpackaged version, you will have to either 129 | rely on container images or compile the necessary extensions manually. Both 130 | approaches are :ref:`described in the dedicated 131 | section`: 132 | 133 | Configure the PostgreSQL instance 134 | --------------------------------- 135 | 136 | Once all extensions are installed or compiled, add the required modules to 137 | `shared_preload_libraries` in the `postgresql.conf` of your instance: 138 | 139 | .. code-block:: ini 140 | 141 | shared_preload_libraries='pg_stat_statements,powa,pg_stat_kcache,pg_qualstats,pg_wait_sampling' 142 | 143 | Now restart PostgreSQL: 144 | 145 | .. tabs:: 146 | 147 | .. code-tab:: bash RHEL / Rocky 148 | 149 | sudo systemctl restart postgresql-14 150 | 151 | .. code-tab:: bash Debian / Ubuntu 152 | 153 | sudo pg_ctlcluster 14 main restart 154 | 155 | Log in to your PostgreSQL as a superuser and create a `powa` database: 156 | 157 | .. code-block:: sql 158 | 159 | CREATE DATABASE powa ; 160 | 161 | Create the required extensions in this new database: 162 | 163 | .. code-block:: psql 164 | 165 | \c powa 166 | CREATE EXTENSION pg_stat_statements; 167 | CREATE EXTENSION btree_gist; 168 | CREATE EXTENSION powa; 169 | CREATE EXTENSION pg_qualstats; 170 | CREATE EXTENSION pg_stat_kcache; 171 | CREATE EXTENSION pg_wait_sampling; 172 | CREATE EXTENSION pg_track_settings; 173 | 174 | PoWA needs the `hypopg` extension in all databases of the cluster in order to 175 | check that the suggested indexes are efficient: 176 | 177 | .. code-block:: sql 178 | 179 | CREATE EXTENSION hypopg; 180 | 181 | One last step is to create a role that has superuser privileges and is able to 182 | login to the cluster (use your own credentials): 183 | 184 | .. code-block:: sql 185 | 186 | CREATE ROLE powa SUPERUSER LOGIN PASSWORD 'astrongpassword' ; 187 | 188 | .. note:: 189 | 190 | This command is just an example. We strongly advise you to look at the 191 | `authentication documentation 192 | `_ 193 | and to properly setup this role and the other roles in a secure way. 194 | 195 | The Web UI requires you to log in with a PostgreSQL role that has superuser 196 | privileges as only a superuser can access to the query text in PostgreSQL. PoWA 197 | follows the same principle. 198 | 199 | PoWA is now up and running on the PostgreSQL-side. You still need to set up the 200 | web interface in order to access your history. By default 201 | powa-archivist stores history for 1 day and takes a snapshot every 5 minutes. 202 | These default settings can be easily changed afterwards. 203 | 204 | Install the Web UI 205 | ****************** 206 | 207 | Install from the packages 208 | ------------------------- 209 | 210 | The PGDG packages should work for currently supported Red Hat/Rocky Linux and 211 | Debian / Ubuntu. For unsupported platforms, see :ref:`the installation through 212 | pip` or :ref:`the full manual installation 213 | guide`. 214 | 215 | You can install the web client on any server you like. The only requirement is 216 | that the web client can connect to the previously set up PostgreSQL cluster. 217 | 218 | If you're setting up PoWA on another server, you have to install the PGDG repo 219 | package again. This is required to install the `powa_14-web` package and some 220 | dependencies. 221 | 222 | Again, for example for PostgreSQL 14 on Rocky Linux 8, install the 223 | `powa_14-web` RPM package with its dependencies using: 224 | 225 | .. tabs:: 226 | 227 | .. code-tab:: bash RHEL / Rocky 228 | 229 | sudo dnf install powa_14-web 230 | 231 | .. code-tab:: bash Debian / Ubuntu 232 | 233 | sudo apt install powa-web 234 | 235 | Create the `/etc/powa-web.conf` config-file to tell the UI how to connect to 236 | your freshly installed PoWA database. Of course, change the given cookie to 237 | something from your own. For example to connect to the local instance on 238 | `localhost`: 239 | 240 | .. code-block:: 241 | 242 | servers={ 243 | 'main': { 244 | 'host': 'localhost', 245 | 'port': '5432', 246 | 'database': 'powa' 247 | } 248 | } 249 | cookie_secret="SUPERSECRET_THAT_YOU_SHOULD_CHANGE" 250 | 251 | Don't forget to allow the web server to connect to the PostgreSQL cluster, and 252 | edit your `pg_hba.conf` accordingly. 253 | 254 | Then, run powa-web: 255 | 256 | .. code-block:: bash 257 | 258 | powa-web 259 | 260 | The Web UI is now available on port 8888, 261 | for example on http://localhost:8888/. 262 | You may have to configure your firewall to open the access to the outside. 263 | Use the role created earlier in PostgreSQL to connect to the UI. 264 | 265 | 266 | .. _powa-web-from-pip: 267 | 268 | Install powa-web from pip 269 | ------------------------- 270 | 271 | You do not have to install the GUI on the same machine your instance is running. 272 | 273 | Prerequisites 274 | ------------- 275 | 276 | * The Python language, either 2.6, 2.7 or > 3 277 | * The Python language headers, either 2.6, 2.7 or > 3 278 | * The pip installer for Python. It is usually packaged as **python-pip**, for 279 | example: 280 | 281 | .. tabs:: 282 | 283 | .. code-tab:: bash RHEL / Rocky 284 | 285 | sudo dnf install python-pip python-devel 286 | 287 | .. code-tab:: bash Debian / Ubuntu 288 | 289 | sudo apt-get install python-pip python-dev 290 | 291 | Installation 292 | ------------ 293 | 294 | To install powa-web, just issue the following comamnd: 295 | 296 | .. code-block:: bash 297 | 298 | sudo pip install powa-web 299 | 300 | Then you'll have to configure a config file somewhere, in one of those location: 301 | 302 | * /etc/powa-web.conf 303 | * ~/.config/powa-web.conf 304 | * ~/.powa-web.conf 305 | * ./powa-web.conf 306 | 307 | The configuration file is a simple tornado config file. Copy the following 308 | content to one of the above locations and modify it according to your setup: 309 | 310 | .. code-block:: 311 | 312 | servers={ 313 | 'main': { 314 | 'host': 'localhost', 315 | 'port': '5432', 316 | 'database': 'powa' 317 | } 318 | } 319 | cookie_secret="SUPERSECRET_THAT_YOU_SHOULD_CHANGE" 320 | 321 | The servers key define a list of server available for connection by PoWA-web. 322 | You should ensure that the pg_hba.conf file is properly configured. 323 | 324 | The cookie_secret is used as a key to crypt cookies between the client and the 325 | server. You should DEFINITELY not keep the default if you value your security. 326 | 327 | Other options are described in 328 | :ref:`the full manual installation guide`. 329 | 330 | Then, run powa-web: 331 | 332 | .. code-block:: bash 333 | 334 | powa-web 335 | 336 | The UI is now available on the 8888 port (eg. http://localhost:8888). Login 337 | with the credentials of the `powa` PostgreSQL user. 338 | -------------------------------------------------------------------------------- /docs/releases.rst: -------------------------------------------------------------------------------- 1 | Release Notes 2 | ============= 3 | 4 | The release notes of each component (internal or external) are available at: 5 | 6 | * powa-archivist: https://github.com/powa-team/powa-archivist/releases 7 | * powa-web: https://github.com/powa-team/powa-web/releases 8 | * powa-collector: https://github.com/powa-team/powa-collector/releases 9 | * HypoPG: https://github.com/HypoPG/hypopg/releases 10 | * pg_qualstats: https://github.com/powa-team/pg_qualstats/releases 11 | * pg_stat_kcache: https://github.com/powa-team/pg_stat_kcache/releases 12 | * pg_wait_sampling: https://github.com/postgrespro/pg_wait_sampling/releases 13 | * pg_track_settings: https://github.com/rjuju/pg_track_settings/releases 14 | 15 | You can also consult these page for the major version changlog: 16 | 17 | .. toctree:: 18 | :maxdepth: 1 19 | 20 | releases/v4.0.0 21 | releases/v3.0.0 22 | releases/v2.0 23 | -------------------------------------------------------------------------------- /docs/releases/v2.0.rst: -------------------------------------------------------------------------------- 1 | What's new in PoWA 2.0 2 | ====================== 3 | 4 | **March 2, 2015** 5 | 6 | New User Interface 7 | ------------------ 8 | 9 | * The web interface is now a seprate module called ``powa-web`` 10 | * Complete rewite of the previous HTML UI 11 | * We dropped mojolicious and use Tornado instead 12 | * New Bar Graph 13 | * New configuration view 14 | * New index suggestion widget 15 | * New physical resource consumption graphs 16 | * Pie Charts 17 | * Histogramm for qual constants values 18 | * Better Global Query Chart 19 | * Breadcrumbs 20 | * Check PoWA installation on login 21 | * Python 2.6, 2.7 and 3.4 compatibility 22 | 23 | New Stat sources 24 | ---------------- 25 | 26 | * The core engine is now a seprate module called ``powa-archivist`` 27 | * Integration of pg_qualstats 28 | * Integration of pg_stat_kcache 29 | 30 | 31 | Documentation 32 | -------------- 33 | 34 | * Complete user documentation available at https://powa.readthedocs.io/ 35 | 36 | Backward compatibility 37 | ---------------------- 38 | 39 | * PoWA 2.0 and later is NOT COMPATIBLE with PostgreSQL 9.3. If you're using PoWA with PostgreSQL 9.3, you can either keep PoWA 1.2 or upgrade to PostgreSQL 9.4 and switch to PoWA 2.0. 40 | -------------------------------------------------------------------------------- /docs/releases/v3.0.0.rst: -------------------------------------------------------------------------------- 1 | What's new in PoWA 3.0.0 2 | ========================= 3 | 4 | **December 7, 2015** 5 | 6 | Better predicate analyzer 7 | ------------------------- 8 | 9 | The pg_qualstats (https://github.com/powa-team/pg_qualstats) extension stores 10 | new counters. It's now possible to know the most executed predicates in 11 | relation to all the related queries. It also tracks non-normalized queries so 12 | that it’s possible to execute an EXPLAIN of any query tracked by pg\_stat\_statements. 13 | 14 | 15 | Database global optimization 16 | ---------------------------- 17 | 18 | PoWA is now able to use statistics about every predicate used by any query 19 | executed on a database to suggest the smallest index set that optimizes every 20 | one of those predicates. 21 | 22 | In particular, the heuristics place heavy emphasis in consolidating many 23 | indexes into one by giving preference to definitions spanning multiple 24 | columns. This can provide new information about the actual load and correlation 25 | between predicates that are traditionally hard to discover for the DBA. 26 | 27 | Index suggestion check 28 | ---------------------- 29 | 30 | Thanks to the HypoPG (https://github.com/hypopg/hypopg) extension, the 31 | benefits of the suggested index creations can automatically be checked by 32 | running the queries against hypothetical indexes. You can see instantly if the 33 | suggested index is relevant and how much it'll improve the query. 34 | 35 | 36 | Documentation 37 | ---------------------- 38 | 39 | * Complete user documentation available at https://powa.readthedocs.io/ 40 | 41 | Backward compatibility 42 | ------------------------------ 43 | 44 | * PoWA 2.0 and later is NOT COMPATIBLE with PostgreSQL 9.3. If you're using PoWA 45 | with PostgreSQL 9.3, you can either keep PoWA 1.2 or upgrade to PostgreSQL 9.4 46 | and switch to PoWA 3.0.0. 47 | -------------------------------------------------------------------------------- /docs/releases/v4.0.0.rst: -------------------------------------------------------------------------------- 1 | What's new in PoWA 4.0.0 2 | ========================= 3 | 4 | **April, 8, 2020** 5 | 6 | New remote mode 7 | --------------- 8 | 9 | The new remote mode is the biggest feature introduced in PoWA 4, though there 10 | have been other improvements. 11 | 12 | With this new mode you can now store the metrics from the various datasources 13 | (pg_stat_statements, pg_stat_kcache and any other) on a different PostgreSQL 14 | server. You can therefore use PoWA without provisionning extra disk space on 15 | your production instances, or spend any other resource for the data 16 | collection as it's all done on a different server. Thanks to this mode it's 17 | also now possible to use PoWA with read-only physical replication standby 18 | servers. And finally with this new mode you can also store the PoWA metrics 19 | from any number of PostgreSQL servers in a single place and access everything 20 | using the same web interface. 21 | 22 | A new dedicated daemon called powa-collector is provided to take retrieve the 23 | various PoWA metrics from all the instances and store them on the wanted 24 | server. 25 | 26 | A lot of other enhancements 27 | --------------------------- 28 | 29 | As for any other new PoWA versions, a lot of other things have been improved. 30 | 31 | This versions adds compatibility with the PostgreSQL 13 and with the new 32 | metrics added in pg_stat_kcache 2.1.0 and pg_qualstats 2.0.0. 33 | 34 | The web interface has a new page to show all the remote servers for which PoWA 35 | is storing data and inspect any of them. It also adds new widgets for 36 | pg_track_settings, showing any detected configuration changes or server 37 | restarts as events on the varioius graphs. Multiple other graphs have been 38 | added and all the graphs get in-app metrics documentation, with optional link 39 | to some documentation when needed. 40 | 41 | Documentation 42 | ------------- 43 | 44 | * Complete powa-archivist changelog available at 45 | https://github.com/powa-team/powa-archivist/blob/master/CHANGELOG.md#400 46 | * Complete powa-web changelog available at 47 | https://github.com/powa-team/powa-web/blob/master/CHANGELOG 48 | * Complete user documentation available at https://powa.readthedocs.io/ 49 | -------------------------------------------------------------------------------- /docs/remote_setup.rst: -------------------------------------------------------------------------------- 1 | .. _remote_setup: 2 | 3 | Remote setup 4 | ============ 5 | 6 | This page covers the additional steps required to go from a "local mode" setup 7 | (as described in the :ref:`quickstart` guide) to a "remote mode" setup, which 8 | allows to store metrics from multiple servers, possibly physical standby 9 | servers, on a single repository server. 10 | 11 | If you haven't done so already, please refer to the :ref:`architecture` page 12 | for more detail on the "local mode" and "remote mode". 13 | 14 | For conveniency, here's the schema for this "remote mode" architecture: 15 | 16 | .. image:: /images/powa_4_remote.svg 17 | :width: 800 18 | :alt: Remote mode diagram 19 | 20 | This chapter describes how to configure such remote mode. 21 | 22 | Overview of the changes 23 | *********************** 24 | 25 | Basically, with the remote mode you now setup the new **powa-collector** to 26 | perform the snapshots and store them on a new, usually dedicated, repository 27 | postgres instance rather than using a background worker that saves the changes 28 | locally. 29 | 30 | What did not change 31 | ******************* 32 | 33 | Only the storage part changed. Therefore, it's still mandatory to configure at 34 | least :ref:`pg_stat_statements_doc` on each PostgreSQL instance, and all the 35 | other :ref:`stat_extensions` you want to use. The list of extension can of 36 | course be different on each instance. 37 | 38 | Setup the main repository database 39 | ********************************** 40 | 41 | A PostgreSQL 9.4 or upward is required. Ideally, you should setup a dedicated 42 | instance for storing the PoWA performance data, especially if you want to setup 43 | more than a few remote servers. 44 | 45 | You need to setup a dedicated database and install the latest version of 46 | :ref:`powa_archivist`. The :ref:`powa-archivist_installation` and 47 | :ref:`powa-archivist-configuration` documentation will explain in detail how to 48 | do so. 49 | 50 | However, please note that if you don't want to gather performance data for the 51 | repository PostgreSQL server, the `shared_preload_libraries` configuration and 52 | instance restart is not required anymore. 53 | 54 | Configure PoWA and stats extensions on each remote server 55 | ********************************************************* 56 | 57 | You need to install and configure :ref:`powa_archivist` and the 58 | :ref:`stat_extensions` of your choice on each remote PostgreSQL server. 59 | 60 | Declare the list of remote servers and their extensions 61 | ******************************************************* 62 | 63 | :ref:`powa_archivist` provides some SQL functions for that. 64 | 65 | You most likely want to declare a *remote sever* using the 66 | `powa_register_server` function. For instance: 67 | 68 | .. code-block:: sql 69 | 70 | SELECT powa_register_server(hostname => 'myserver.domain.com', 71 | alias => 'myserver', 72 | password => 'mypassword', 73 | extensions => '{pg_stat_kcache,pg_qualstats,pg_wait_sampling}'); 74 | 75 | You can consult the :ref:`powa_archivist_remote_servers_configuration` page 76 | for a full documentation of the available SQL API. 77 | 78 | Configure powa-collector 79 | ************************ 80 | 81 | Do all the required configuration as documented in :ref:`powa_collector`. 82 | 83 | Then you can check that everything is working by simply launching the 84 | collector. For instance: 85 | 86 | .. code-block:: bash 87 | 88 | ./powa-collector.py 89 | 90 | .. warning:: 91 | 92 | It's highly recommended to configure powa-collector as a daemon, with any 93 | facility provided by your operating system, once the initial setup and 94 | testing is finished. 95 | 96 | Gathering of remote data will start, as described by previous configuration. 97 | 98 | Configure the User Interface 99 | **************************** 100 | 101 | You can follow the :ref:`powa_web` documentation. Obviously, in case of remote 102 | setup you only need to configure a single connection information per PoWA 103 | remote repository. 104 | 105 | 106 | Once all those steps are finished, you should have a working remote setup for 107 | PoWA! 108 | -------------------------------------------------------------------------------- /docs/requirements.txt: -------------------------------------------------------------------------------- 1 | sphinxcontrib-napoleon 2 | requests 3 | sphinxcontrib-domaintools 4 | sphinx_rtd_theme 5 | sphinx-tabs 6 | sphinx-autobuild 7 | -------------------------------------------------------------------------------- /docs/security.rst: -------------------------------------------------------------------------------- 1 | Security 2 | ======== 3 | 4 | PoWA-web 5 | ******** 6 | 7 | .. warning:: 8 | 9 | 10 | **You need to be careful about the security of your PostgreSQL instance when 11 | installing PoWA.** 12 | 13 | We designed POWA so that the user interface will only communicate with 14 | PostgreSQL via prepared statements. This will prevent the risk of `SQL 15 | injection `_. 16 | 17 | However to connect to the PoWA User Interface, you will use the login and 18 | password of a PostgreSQL user. If you don't protect your communications, an 19 | attacker placed between the GUI and PostgreSQL, or between you and the GUI, 20 | could gain your user rights to your database server. 21 | 22 | Therefore we **strongly** recommend the following precautions: 23 | 24 | * `Read the Great PostgreSQL Documentation `_ 25 | * Check your *pg_hba.conf* file 26 | * Do not allow users to access PoWA from the Internet 27 | * Do not allow users to access PostgreSQL from the Internet 28 | * Run PoWA on a HTTPS server and disable HTTP access 29 | * Use SSL to protect the connection between the GUI and PostgreSQL 30 | * Reject unprotected connections between the GUI and PostgreSQL (*hostnossl .... reject*) 31 | * Check your *pg_hba.conf* file again 32 | 33 | Please also note that you need to manually authorize the roles to see the data 34 | in the powa database. For instance, you might run: 35 | 36 | .. code-block:: sql 37 | 38 | powa=# GRANT SELECT ON ALL TABLES IN SCHEMA public TO ui_user; 39 | powa=# GRANT SELECT ON pg_statistic TO ui_user; 40 | 41 | User objects 42 | ------------ 43 | 44 | powa-web will connect to the databases you select to help you optimize them. 45 | 46 | Therefore, for each postgres roles using powa, you also need to: 47 | 48 | * grant **SELECT** privilege on the pg\_statistic and the user tables (don't 49 | forget tables that aren't in the public schema). 50 | * give **CONNECT** privilege on the databases. 51 | 52 | If you don't, some useful parts of the UI won't work as intended. 53 | 54 | TLS and default HTTP/HTTPS ports 55 | -------------------------------- 56 | 57 | As powa-web is just a python script, it's probably better not to run it as 58 | root. This means it won't be able to bind to the default HTTP (or HTTPS) port. 59 | 60 | The most secure way of doing is putting a reverse proxy, like nginx, in front 61 | of it. You'll also get the possibility of using an SSL certificate (which can 62 | be also done using powa-web script, but is not recommended due to the same 63 | security concerns). 64 | 65 | PoWA-archivist & PoWA-collector in remote mode 66 | ********************************************** 67 | 68 | Connection on remote servers 69 | ---------------------------- 70 | 71 | With PoWA version 4 and newer, you can register *remote servers* in the 72 | `powa_servers` table (usually using the `powa_register_server` function). 73 | 74 | This table can optionally store a **password** to connect on this remote 75 | server. If the password is NULL, the connection will then be attempted using 76 | `the authentication method that libpq supports 77 | `_ of your choice. 78 | 79 | Storing a plain text password in this table is definitely **NOT** a best 80 | practice, and we encourage you to rely on the `other libpq authentication 81 | methods `_. 82 | 83 | Required privileges on remote servers 84 | ------------------------------------- 85 | 86 | In order to perform the metric snapshots, the role defined to connect on the 87 | remote servers requires the following privilege for each remote server: 88 | 89 | * remote servers 90 | 91 | * for PostgreSQL 9.6 and lower: a superuser role 92 | 93 | * for PostgreSQL 10 and above: either a superuser role or a roler member of 94 | the group **pg_read_all_stats** (see the `default roles documentation 95 | `_) 96 | 97 | * repository servers 98 | 99 | * read & write privileges on all the PoWA tables 100 | 101 | * remote & repository servers 102 | 103 | * execute privilege on all the PoWA functions 104 | -------------------------------------------------------------------------------- /docs/support.rst: -------------------------------------------------------------------------------- 1 | .. _support: 2 | 3 | Support 4 | ======= 5 | 6 | Community Support 7 | ----------------- 8 | 9 | You can join directly the developer team on the #powa channel of the freenode 10 | IRC network. 11 | 12 | To report an issue, please use the bug tracking system in the github page of 13 | the underlying project: 14 | 15 | * https://github.com/powa-team/powa-web/issues for an issue on the UI 16 | * https://github.com/powa-team/powa-archivist/issues for an issue on the background worker 17 | * https://github.com/powa-team/powa-collector/issues for an issue on the collector daemon 18 | * https://github.com/powa-team/pg_qualstats/issues for an issue on pg_qualstats 19 | * https://github.com/powa-team/pg_stat_kcache/issues for an issue on pg_stat_kcache 20 | * https://github.com/postgrespro/pg_wait_sampling/issues for an issue on pg_wait_sampling 21 | * https://github.com/rjuju/pg_track_settings/issues for an issue on pg_track_settings 22 | * https://github.com/HypoPG/hypopg/issues for an issue on HypoPG 23 | -------------------------------------------------------------------------------- /img/powa_logo.410x161.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/powa-team/powa/181373453ccee970b92f1fea4184b6720f3cfcf7/img/powa_logo.410x161.png --------------------------------------------------------------------------------