├── .gitattributes ├── .gitignore ├── .readthedocs.yaml ├── COPYRIGHT ├── COPYRIGHT.postgresql ├── META.json ├── Makefile ├── README.md ├── SPECS └── pg_hint_plan18.spec ├── core.c ├── data └── data.csv ├── docs ├── Makefile ├── README ├── conf.py ├── description.md ├── errors.md ├── functional_limitations.md ├── hint_details.md ├── hint_list.md ├── hint_table.md ├── index.md ├── installation.md ├── locale │ └── ja │ │ └── LC_MESSAGES │ │ ├── description.po │ │ ├── errors.po │ │ ├── functional_limitations.po │ │ ├── hint_details.po │ │ ├── hint_list.po │ │ ├── hint_table.po │ │ ├── index.po │ │ ├── installation.po │ │ ├── requirements.po │ │ ├── synopsis.po │ │ └── uninstallation.po ├── make.bat ├── requirements.in ├── requirements.md ├── requirements.txt ├── synopsis.md └── uninstallation.md ├── expected ├── R_sample.out ├── base_plan.out ├── hint_table.out ├── init.out ├── oldextversions.out ├── pg_hint_plan.out ├── plpgsql.out ├── ut-A.out ├── ut-G.out ├── ut-J.out ├── ut-L.out ├── ut-R.out ├── ut-S.out ├── ut-T.out ├── ut-W.out ├── ut-fdw.out ├── ut-fini.out └── ut-init.out ├── make_join_rel.c ├── pg_hint_plan--1.3.0--1.3.1.sql ├── pg_hint_plan--1.3.0.sql ├── pg_hint_plan--1.3.1--1.3.2.sql ├── pg_hint_plan--1.3.10--1.4.sql ├── pg_hint_plan--1.3.2--1.3.3.sql ├── pg_hint_plan--1.3.3--1.3.4.sql ├── pg_hint_plan--1.3.4--1.3.5.sql ├── pg_hint_plan--1.3.5--1.3.6.sql ├── pg_hint_plan--1.3.6--1.3.7.sql ├── pg_hint_plan--1.3.7--1.3.8.sql ├── pg_hint_plan--1.3.8--1.3.9.sql ├── pg_hint_plan--1.3.9--1.3.10.sql ├── pg_hint_plan--1.4--1.4.1.sql ├── pg_hint_plan--1.4.1--1.4.2.sql ├── pg_hint_plan--1.4.2--1.4.3.sql ├── pg_hint_plan--1.4.3--1.5.sql ├── pg_hint_plan--1.5--1.5.1.sql ├── pg_hint_plan--1.5.1--1.5.2.sql ├── pg_hint_plan--1.5.2--1.6.0.sql ├── pg_hint_plan--1.6.0--1.6.1.sql ├── pg_hint_plan--1.6.1--1.7.0.sql ├── pg_hint_plan--1.7.0--1.8.0.sql ├── pg_hint_plan.c ├── pg_hint_plan.control ├── query_scan.h ├── query_scan.l ├── query_scan_int.h ├── sql ├── base_plan.sql ├── hint_table.sql ├── init.sql ├── oldextversions.sql ├── pg_hint_plan.sql ├── plpgsql.sql ├── ut-A.sql ├── ut-G.sql ├── ut-J.sql ├── ut-L.sql ├── ut-R.sql ├── ut-S.sql ├── ut-T.sql ├── ut-W.sql ├── ut-fdw.sql ├── ut-fini.sql └── ut-init.sql └── update_copied_funcs.pl /.gitattributes: -------------------------------------------------------------------------------- 1 | # Test output files that contain extra whitespace 2 | *.out -whitespace 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Global excludes across all subdirectories 2 | *.o 3 | *.so 4 | *.bc 5 | tags 6 | regression.* 7 | *.tar.gz 8 | *~ 9 | 10 | # Generated subdirectories 11 | /.deps/ 12 | /log/ 13 | /results/ 14 | /tmp_check/ 15 | /RPMS/ 16 | 17 | # Generated files 18 | /query_scan.c 19 | 20 | # Documentation artifacts 21 | docs/_build 22 | docs/locale/**/*.mo 23 | -------------------------------------------------------------------------------- /.readthedocs.yaml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | build: 4 | os: ubuntu-22.04 5 | tools: 6 | python: "3.12" 7 | jobs: 8 | pre_install: 9 | # The following code is necessary to avoid PyYAML installation errors. 10 | # See https://github.com/yaml/pyyaml/issues/724#issuecomment-1638636728 11 | - python -m pip install --upgrade --no-cache-dir --no-build-isolation pyyaml==6.0 12 | 13 | sphinx: 14 | configuration: docs/conf.py 15 | 16 | formats: all 17 | 18 | python: 19 | install: 20 | - requirements: docs/requirements.txt 21 | -------------------------------------------------------------------------------- /COPYRIGHT: -------------------------------------------------------------------------------- 1 | Copyright (c) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, 8 | this list of conditions and the following disclaimer. 9 | * Redistributions in binary form must reproduce the above copyright 10 | notice, this list of conditions and the following disclaimer in the 11 | documentation and/or other materials provided with the distribution. 12 | * Neither the name of the NIPPON TELEGRAPH AND TELEPHONE CORPORATION 13 | (NTT) nor the names of its contributors may be used to endorse or 14 | promote products derived from this software without specific prior 15 | written permission. 16 | 17 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 18 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 19 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 20 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 21 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 22 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 23 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 24 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 25 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 26 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 27 | -------------------------------------------------------------------------------- /COPYRIGHT.postgresql: -------------------------------------------------------------------------------- 1 | core.c and make_join_rel.c are the parts of PostgreSQL Database Management 2 | System (formerly known as Postgres, then as Postgres95). 3 | Copyright holders of those files are following organizations: 4 | 5 | Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group 6 | 7 | Portions Copyright (c) 1994, The Regents of the University of California 8 | 9 | Permission to use, copy, modify, and distribute this software and its 10 | documentation for any purpose, without fee, and without a written agreement 11 | is hereby granted, provided that the above copyright notice and this 12 | paragraph and the following two paragraphs appear in all copies. 13 | 14 | IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR 15 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 16 | LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS 17 | DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE 18 | POSSIBILITY OF SUCH DAMAGE. 19 | 20 | THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES, 21 | INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY 22 | AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS 23 | ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO 24 | PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 25 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg_hint_plan18", 3 | "abstract": "Query hints in SQL comments", 4 | "description": "This library adds support for query hints in SQL comments in PostgreSQL 18.", 5 | "version": "1.8.0", 6 | "maintainer": [ 7 | "Michael Paquier " 8 | ], 9 | "license": "bsd", 10 | "prereqs": { 11 | "runtime": { 12 | "requires": { 13 | "PostgreSQL": ">= 18.0.0, < 19.0.0" 14 | } 15 | } 16 | }, 17 | "provides": { 18 | "pg_hint_plan": { 19 | "abstract": "Query hints in SQL comments", 20 | "file": "pg_hint_plan--1.3.0.sql", 21 | "docfile": "README.md", 22 | "version": "1.8.0" 23 | } 24 | }, 25 | "resources": { 26 | "bugtracker": { 27 | "web": "https://github.com/ossc-db/pg_hint_plan/issues" 28 | }, 29 | "repository": { 30 | "url": "https://github.com/ossc-db/pg_hint_plan.git", 31 | "web": "https://github.com/ossc-db/pg_hint_plan/", 32 | "type": "git" 33 | } 34 | }, 35 | "meta-spec": { 36 | "version": "1.0.0", 37 | "url": "https://pgxn.org/meta/spec.txt" 38 | }, 39 | "tags": [ 40 | "sql", 41 | "plan", 42 | "performance", 43 | "hint" 44 | ] 45 | } 46 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # 2 | # pg_hint_plan: Makefile 3 | # 4 | # Copyright (c) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 5 | # 6 | 7 | MODULE_big = pg_hint_plan 8 | OBJS = \ 9 | $(WIN32RES) \ 10 | pg_hint_plan.o \ 11 | query_scan.o 12 | 13 | HINTPLANVER = 1.8.0 14 | 15 | REGRESS = init base_plan pg_hint_plan ut-init ut-A ut-S ut-J ut-L ut-G ut-R \ 16 | ut-fdw ut-W ut-T ut-fini plpgsql hint_table oldextversions 17 | REGRESS_OPTS = --encoding=UTF8 18 | 19 | EXTENSION = pg_hint_plan 20 | DATA = \ 21 | pg_hint_plan--1.3.0.sql \ 22 | pg_hint_plan--1.3.0--1.3.1.sql \ 23 | pg_hint_plan--1.3.1--1.3.2.sql \ 24 | pg_hint_plan--1.3.2--1.3.3.sql \ 25 | pg_hint_plan--1.3.3--1.3.4.sql \ 26 | pg_hint_plan--1.3.5--1.3.6.sql \ 27 | pg_hint_plan--1.3.4--1.3.5.sql \ 28 | pg_hint_plan--1.3.6--1.3.7.sql \ 29 | pg_hint_plan--1.3.7--1.3.8.sql \ 30 | pg_hint_plan--1.3.8--1.3.9.sql \ 31 | pg_hint_plan--1.3.9--1.3.10.sql \ 32 | pg_hint_plan--1.3.10--1.4.sql \ 33 | pg_hint_plan--1.4--1.4.1.sql \ 34 | pg_hint_plan--1.4.1--1.4.2.sql \ 35 | pg_hint_plan--1.4.2--1.4.3.sql \ 36 | pg_hint_plan--1.4.3--1.5.sql \ 37 | pg_hint_plan--1.5--1.5.1.sql \ 38 | pg_hint_plan--1.5.1--1.5.2.sql \ 39 | pg_hint_plan--1.5.2--1.6.0.sql \ 40 | pg_hint_plan--1.6.0--1.6.1.sql \ 41 | pg_hint_plan--1.6.1--1.7.0.sql \ 42 | pg_hint_plan--1.7.0--1.8.0.sql 43 | 44 | EXTRA_CLEAN = RPMS 45 | 46 | # Switch environment between standalone make and make check with 47 | # EXTRA_INSTALL from PostgreSQL tree 48 | # run the following command in the PG tree to run a regression test 49 | # loading this module. 50 | # $ make check EXTRA_INSTALL= EXTRA_REGRESS_OPTS="--temp-config /pg_hint_plan.conf" 51 | ifeq ($(wildcard $(DESTDIR)/../src/Makefile.global),) 52 | PG_CONFIG = pg_config 53 | PGXS := $(shell $(PG_CONFIG) --pgxs) 54 | include $(PGXS) 55 | else 56 | subdir = `pwd` 57 | top_builddir = $(DESTDIR)/.. 58 | include $(DESTDIR)/../src/Makefile.global 59 | include $(DESTDIR)/../contrib/contrib-global.mk 60 | endif 61 | 62 | STARBALL18 = pg_hint_plan18-$(HINTPLANVER).tar.gz 63 | STARBALLS = $(STARBALL18) 64 | 65 | TARSOURCES = Makefile *.c *.h COPYRIGHT* \ 66 | pg_hint_plan--*.sql \ 67 | pg_hint_plan.control \ 68 | docs/* expected/*.out sql/*.sql \ 69 | data/data.csv SPECS/*.spec 70 | 71 | rpms: rpm18 72 | 73 | # pg_hint_plan.c includes core.c and make_join_rel.c 74 | pg_hint_plan.o: core.c make_join_rel.c 75 | 76 | $(STARBALLS): $(TARSOURCES) 77 | if [ -h $(subst .tar.gz,,$@) ]; then rm $(subst .tar.gz,,$@); fi 78 | if [ -e $(subst .tar.gz,,$@) ]; then \ 79 | echo "$(subst .tar.gz,,$@) is not a symlink. Stop."; \ 80 | exit 1; \ 81 | fi 82 | ln -s . $(subst .tar.gz,,$@) 83 | tar -chzf $@ $(addprefix $(subst .tar.gz,,$@)/, $^) 84 | rm $(subst .tar.gz,,$@) 85 | 86 | rpm18: $(STARBALL18) 87 | MAKE_ROOT=`pwd` rpmbuild -bb SPECS/pg_hint_plan18.spec 88 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pg\_hint\_plan 1.8 2 | 3 | `pg_hint_plan` makes it possible to tweak PostgreSQL execution plans using 4 | so-called "hints" in SQL comments, like `/*+ SeqScan(a) */`. 5 | 6 | PostgreSQL uses a cost-based optimizer, that uses data statistics, not static 7 | rules. The planner (optimizer) estimates costs of each possible execution 8 | plans for a SQL statement, then executes the plan with the lowest cost. 9 | The planner does its best to select the best execution plan, but it is far 10 | from perfect, since it may not count some data properties, like correlation 11 | between columns. 12 | 13 | For more details, please see the various documentations available in the 14 | **docs/** directory: 15 | 16 | 1. [Description](docs/description.md) 17 | 1. [The hint table](docs/hint_table.md) 18 | 1. [Installation](docs/installation.md) 19 | 1. [Uninstallation](docs/uninstallation.md) 20 | 1. [Details in hinting](docs/hint_details.md) 21 | 1. [Errors](docs/errors.md) 22 | 1. [Functional limitations](docs/functional_limitations.md) 23 | 1. [Requirements](docs/requirements.md) 24 | 1. [Hints list](docs/hint_list.md) 25 | 26 | * * * * * 27 | 28 | Copyright (c) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 29 | -------------------------------------------------------------------------------- /SPECS/pg_hint_plan18.spec: -------------------------------------------------------------------------------- 1 | # SPEC file for pg_hint_plan 2 | # Copyright(c) 2022-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | 4 | %define _pgdir /usr/pgsql-18 5 | %define _bindir %{_pgdir}/bin 6 | %define _libdir %{_pgdir}/lib 7 | %define _datadir %{_pgdir}/share 8 | %define _bcdir %{_libdir}/bitcode 9 | %define _mybcdir %{_bcdir}/pg_hint_plan 10 | 11 | %if "%(echo ${MAKE_ROOT})" != "" 12 | %define _rpmdir %(echo ${MAKE_ROOT})/RPMS 13 | %define _sourcedir %(echo ${MAKE_ROOT}) 14 | %endif 15 | 16 | ## Set general information for pg_hint_plan. 17 | Summary: Optimizer hint on PostgreSQL 18 18 | Name: pg_hint_plan18 19 | Version: 1.8.0 20 | Release: 1%{?dist} 21 | License: BSD 22 | Group: Applications/Databases 23 | Source0: %{name}-%{version}.tar.gz 24 | URL: https://github.com/ossc-db/pg_hint_plan 25 | BuildRoot: %{_tmppath}/%{name}-%{version}-%{release}-%(%{__id_u} -n) 26 | Vendor: NIPPON TELEGRAPH AND TELEPHONE CORPORATION 27 | 28 | ## We use postgresql-devel package 29 | BuildRequires: postgresql18-devel 30 | Requires: postgresql18-server 31 | 32 | ## Description for "pg_hint_plan" 33 | %description 34 | 35 | pg_hint_plan provides capability to tweak execution plans to be 36 | executed on PostgreSQL. 37 | 38 | Note that this package is available for only PostgreSQL 18. 39 | 40 | %package llvmjit 41 | Requires: postgresql18-server, postgresql18-llvmjit 42 | Requires: pg_hint_plan18 = 1.8.0 43 | Summary: Just-in-time compilation support for pg_hint_plan18 44 | 45 | %description llvmjit 46 | Just-in-time compilation support for pg_hint_plan18 47 | 48 | ## pre work for build pg_hint_plan 49 | %prep 50 | PATH=/usr/pgsql-18/bin:$PATH 51 | if [ "${MAKE_ROOT}" != "" ]; then 52 | pushd ${MAKE_ROOT} 53 | make clean %{name}-%{version}.tar.gz 54 | popd 55 | fi 56 | if [ ! -d %{_rpmdir} ]; then mkdir -p %{_rpmdir}; fi 57 | %setup -q 58 | 59 | ## Set variables for build environment 60 | %build 61 | PATH=/usr/pgsql-18/bin:$PATH 62 | make USE_PGXS=1 LDFLAGS+=-Wl,--build-id %{?_smp_mflags} 63 | 64 | ## Set variables for install 65 | %install 66 | rm -rf %{buildroot} 67 | make install DESTDIR=%{buildroot} 68 | 69 | %clean 70 | rm -rf %{buildroot} 71 | 72 | %files 73 | %defattr(0755,root,root) 74 | %{_libdir}/pg_hint_plan.so 75 | %defattr(0644,root,root) 76 | %{_datadir}/extension/pg_hint_plan--1.3.0.sql 77 | %{_datadir}/extension/pg_hint_plan--1.3.0--1.3.1.sql 78 | %{_datadir}/extension/pg_hint_plan--1.3.1--1.3.2.sql 79 | %{_datadir}/extension/pg_hint_plan--1.3.2--1.3.3.sql 80 | %{_datadir}/extension/pg_hint_plan--1.3.3--1.3.4.sql 81 | %{_datadir}/extension/pg_hint_plan--1.3.4--1.3.5.sql 82 | %{_datadir}/extension/pg_hint_plan--1.3.5--1.3.6.sql 83 | %{_datadir}/extension/pg_hint_plan--1.3.6--1.3.7.sql 84 | %{_datadir}/extension/pg_hint_plan--1.3.7--1.3.8.sql 85 | %{_datadir}/extension/pg_hint_plan--1.3.8--1.3.9.sql 86 | %{_datadir}/extension/pg_hint_plan--1.3.9--1.3.10.sql 87 | %{_datadir}/extension/pg_hint_plan--1.3.10--1.4.sql 88 | %{_datadir}/extension/pg_hint_plan--1.4--1.4.1.sql 89 | %{_datadir}/extension/pg_hint_plan--1.4.1--1.4.2.sql 90 | %{_datadir}/extension/pg_hint_plan--1.4.2--1.4.3.sql 91 | %{_datadir}/extension/pg_hint_plan--1.4.3--1.5.sql 92 | %{_datadir}/extension/pg_hint_plan--1.5--1.5.1.sql 93 | %{_datadir}/extension/pg_hint_plan--1.5.1--1.5.2.sql 94 | %{_datadir}/extension/pg_hint_plan--1.5.2--1.6.0.sql 95 | %{_datadir}/extension/pg_hint_plan--1.6.0--1.6.1.sql 96 | %{_datadir}/extension/pg_hint_plan--1.6.1--1.7.0.sql 97 | %{_datadir}/extension/pg_hint_plan--1.7.0--1.8.0.sql 98 | %{_datadir}/extension/pg_hint_plan.control 99 | 100 | %files llvmjit 101 | %defattr(0755,root,root) 102 | %{_mybcdir} 103 | %defattr(0644,root,root) 104 | %{_bcdir}/pg_hint_plan.index.bc 105 | %{_mybcdir}/pg_hint_plan.bc 106 | 107 | # History of pg_hint_plan. 108 | %changelog 109 | * Mon Jul 22 2024 Michael Paquier 110 | - Support PostgreSQL 18. 111 | -------------------------------------------------------------------------------- /data/data.csv: -------------------------------------------------------------------------------- 1 | 1,1 2 | 2,2 3 | 3,3 4 | 4,4 5 | 5,5 6 | 6,6 7 | 7,7 8 | 8,8 9 | 9,9 10 | 10,10 11 | -------------------------------------------------------------------------------- /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 | # Catch-all target: route all unknown targets to Sphinx using the new 18 | # "make mode" option. $(O) is meant as a shortcut for $(SPHINXOPTS). 19 | %: Makefile 20 | @$(SPHINXBUILD) -M $@ "$(SOURCEDIR)" "$(BUILDDIR)" $(SPHINXOPTS) $(O) 21 | -------------------------------------------------------------------------------- /docs/README: -------------------------------------------------------------------------------- 1 | pg_hint_plan documentation 2 | ========================== 3 | 4 | Introduction 5 | ------------ 6 | 7 | Markdown format is kept as a main format, relying on python sphinx and 8 | myst_parser to render an HTML documentation if needed. 9 | 10 | Note that while markdown is more readable as raw text, it's a way simpler 11 | syntax that lacks a lot of features that reStructuredText offers. Relying on 12 | sphinx gives us an opportunity to later write parts of the documentation in 13 | reStructuredText if needed, but also offers other appealing features like 14 | multilingual documentation. 15 | 16 | Readthedocs is the expected target, so use its theme and follow its 17 | recommendation about pinning various requirement versions. 18 | 19 | Building the doc locally 20 | ------------------------ 21 | 22 | The documentation can be built locally easily using 23 | 24 | make -C docs/ html 25 | 26 | The rendered documentation will be generated in docs/html/_build/html 27 | 28 | Note that you need to have all python prerequirements installed, which can be 29 | done using: 30 | 31 | pip install -r docs/requirements.txt 32 | 33 | If you need to update the requirements (which shouldn't be needed frequently), 34 | update the docs/requirements.in and generate the target docs/requirements.txt 35 | using pip-compile. See the link about this tool below for more details on how 36 | to use it. 37 | 38 | Translation 39 | ----------- 40 | 41 | Note that each translator has to follow all those steps whenever the 42 | translation needs to be updated. Note also that those commands assume that the 43 | current working directory is docs/. 44 | 45 | - Bootstrapping the translation (the .pot files) is simply done using 46 | 47 | make gettext 48 | 49 | This will generate the various .pot file in _build/gettext. 50 | 51 | - The per-language translation files (the .po files) can then be generated. We 52 | currently only support Japanese, the rest of the commands will assume a 53 | single Japanese translation. Those files can be generated using: 54 | 55 | sphinx-intl update -p _build/gettext -l ja 56 | 57 | The files are generated (or updated) in the docs/locale/ja/LC_MESSAGES/. 58 | 59 | - You can then translate the .po file with any editor (poedit, vim...) 60 | 61 | - The translated documentation can be built using: 62 | 63 | make -e SPHINXOPTS="-D language='ja'" html 64 | 65 | - If everything is ok, you can commit the modifications in the .po files. 66 | 67 | References 68 | ---------- 69 | 70 | References if you're interested in the various design choices: 71 | 72 | - quickstart for RTD with sphinx: https://docs.readthedocs.io/en/stable/intro/getting-started-with-sphinx.html 73 | - reproducible builds: https://docs.readthedocs.io/en/stable/guides/reproducible-builds.html 74 | - myst parser: https://myst-parser.readthedocs.io 75 | - pip-tools / pip-compile: https://pip-tools.readthedocs.io 76 | - RTD sphinx theme: https://sphinx-rtd-theme.readthedocs.io 77 | - Internationalization: 78 | https://www.sphinx-doc.org/en/master/usage/advanced/intl.html 79 | https://docs.readthedocs.io/en/stable/localization.html#projects-with-multiple-translations-sphinx-only 80 | -------------------------------------------------------------------------------- /docs/conf.py: -------------------------------------------------------------------------------- 1 | # Configuration file for the Sphinx documentation builder. 2 | # 3 | # For the full list of built-in configuration values, see the documentation: 4 | # https://www.sphinx-doc.org/en/master/usage/configuration.html 5 | 6 | # -- Project information ----------------------------------------------------- 7 | # https://www.sphinx-doc.org/en/master/usage/configuration.html#project-information 8 | 9 | project = 'pg_hint_plan' 10 | copyright = '2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION' 11 | author = 'NIPPON TELEGRAPH AND TELEPHONE CORPORATION' 12 | 13 | # -- General configuration --------------------------------------------------- 14 | # https://www.sphinx-doc.org/en/master/usage/configuration.html#general-configuration 15 | 16 | extensions = ['sphinx_rtd_theme', 'myst_parser'] 17 | 18 | templates_path = ['_templates'] 19 | exclude_patterns = ['_build', 'Thumbs.db', '.DS_Store'] 20 | 21 | 22 | 23 | # -- Options for HTML output ------------------------------------------------- 24 | # https://www.sphinx-doc.org/en/master/usage/configuration.html#options-for-html-output 25 | 26 | html_theme = 'sphinx_rtd_theme' 27 | #html_static_path = ['_static'] 28 | 29 | # Internationalization 30 | # https://www.sphinx-doc.org/en/master/usage/advanced/intl.html 31 | # https://docs.readthedocs.io/en/stable/guides/manage-translations-sphinx.html 32 | 33 | locale_dirs = ['locale/'] # path is example but recommended. 34 | gettext_compact = False # optional. 35 | gettext_uuid = True # optional. 36 | -------------------------------------------------------------------------------- /docs/description.md: -------------------------------------------------------------------------------- 1 | # Description 2 | 3 | ## Basic Usage 4 | 5 | `pg_hint_plan` reads hinting phrases in a comment of special form given 6 | a SQL statement. A hint can be specified by prefixing it with the sequence 7 | `"/\*+"` and ending it with `"\*/"`. Hint phrases consist of hint names 8 | and parameters enclosed by parentheses and delimited by whitespaces. Hint 9 | phrases can use newlines for readability. 10 | 11 | In the example below, a hash join is selected as the join method while 12 | doing a sequential scan on `pgbench_accounts`: 13 | 14 | ```sql 15 | =# /*+ 16 | HashJoin(a b) 17 | SeqScan(a) 18 | */ 19 | EXPLAIN SELECT * 20 | FROM pgbench_branches b 21 | JOIN pgbench_accounts a ON b.bid = a.bid 22 | ORDER BY a.aid; 23 | QUERY PLAN 24 | --------------------------------------------------------------------------------------- 25 | Sort (cost=31465.84..31715.84 rows=100000 width=197) 26 | Sort Key: a.aid 27 | -> Hash Join (cost=1.02..4016.02 rows=100000 width=197) 28 | Hash Cond: (a.bid = b.bid) 29 | -> Seq Scan on pgbench_accounts a (cost=0.00..2640.00 rows=100000 width=97) 30 | -> Hash (cost=1.01..1.01 rows=1 width=100) 31 | -> Seq Scan on pgbench_branches b (cost=0.00..1.01 rows=1 width=100) 32 | (7 rows) 33 | ``` 34 | -------------------------------------------------------------------------------- /docs/errors.md: -------------------------------------------------------------------------------- 1 | # Errors 2 | 3 | `pg_hint_plan` stops hint parsing on any error and will uses the hints 4 | already parsed. Here are some typical errors. 5 | 6 | ## Syntax errors 7 | 8 | Any syntactical errors or wrong hint names are reported as a syntax error. 9 | These errors are reported in the server log with the message level specified 10 | by `pg_hint_plan.message_level` if `pg_hint_plan.debug_print` is on and 11 | above. 12 | 13 | ## Incorrect Object definitions 14 | 15 | Incorrect object definitions result in silently ignoring the hints. This kind 16 | of error is reported as a "Not Used Hint" in the server logs. 17 | 18 | ## Redundant or conflicting hints 19 | 20 | The last hint is considered when redundant hints are defined or hints 21 | conflict with each other. This kind of error is reported as a duplicated 22 | hints. 23 | 24 | ## Nested comments 25 | 26 | Hint comments cannot be recursive. If detected, hint parsing is immediately 27 | stopped and all the hints already parsed are ignored. 28 | -------------------------------------------------------------------------------- /docs/functional_limitations.md: -------------------------------------------------------------------------------- 1 | (functional-limitations)= 2 | 3 | # Functional limitations 4 | 5 | ## Influence of planner GUC parameters 6 | 7 | The planner does not try to consider joining order for FROM clause entries 8 | more than `from_collapse_limit`. `pg_hint_plan` cannot affect the joining 9 | order in this case. 10 | 11 | ## Hints trying to enforce non-executable plans 12 | 13 | Planner chooses any executable plans when the enforced plan cannot be 14 | executed: 15 | 16 | - `FULL OUTER JOIN` to use nested loop. 17 | - Use of indexes that do not have columns used in quals. 18 | - TID scans for queries without ctid conditions. 19 | 20 | ## Queries in ECPG 21 | 22 | ECPG removes comments in queries written as embedded SQLs so hints cannot 23 | be passed to it. The only exception `EXECUTE`, that passes the query string 24 | to the server as-is. The hint table can be used in the case. 25 | 26 | ## Query Identifiers 27 | 28 | When `compute_query_id` is enabled, PostgreSQL generates a query ID, 29 | ignoring comments. Hence, queries with different hints, still written 30 | the same way, may compute the same query ID. 31 | -------------------------------------------------------------------------------- /docs/hint_details.md: -------------------------------------------------------------------------------- 1 | # Details in hinting 2 | 3 | ## Syntax and placement 4 | 5 | `pg_hint_plan` reads hints from only the first block comment and stops parsing 6 | from any characters except alphabetical characters, digits, spaces, 7 | underscores, commas and parentheses. In the following example, 8 | `HashJoin(a b)` and `SeqScan(a)` are parsed as hints, but `IndexScan(a)` and 9 | `MergeJoin(a b)` are not: 10 | 11 | ```sql 12 | =# /*+ 13 | HashJoin(a b) 14 | SeqScan(a) 15 | */ 16 | /*+ IndexScan(a) */ 17 | EXPLAIN SELECT /*+ MergeJoin(a b) */ * 18 | FROM pgbench_branches b 19 | JOIN pgbench_accounts a ON b.bid = a.bid 20 | ORDER BY a.aid; 21 | QUERY PLAN 22 | --------------------------------------------------------------------------------------- 23 | Sort (cost=31465.84..31715.84 rows=100000 width=197) 24 | Sort Key: a.aid 25 | -> Hash Join (cost=1.02..4016.02 rows=100000 width=197) 26 | Hash Cond: (a.bid = b.bid) 27 | -> Seq Scan on pgbench_accounts a (cost=0.00..2640.00 rows=100000 width=97) 28 | -> Hash (cost=1.01..1.01 rows=1 width=100) 29 | -> Seq Scan on pgbench_branches b (cost=0.00..1.01 rows=1 width=100) 30 | (7 rows) 31 | ``` 32 | 33 | ## Using with PL/pgSQL 34 | 35 | `pg_hint_plan` works for queries in PL/pgSQL scripts with some restrictions. 36 | 37 | - Hints affect only on the following kind of queries: 38 | - Queries that return one row (`SELECT`, `INSERT`, `UPDATE` and `DELETE`) 39 | - Queries that return multiple rows (`RETURN QUERY`) 40 | - Dynamic SQL statements (`EXECUTE`) 41 | - Cursor open (`OPEN`) 42 | - Loop over result of a query (`FOR`) 43 | - A hint comment has to be placed after the first word in a query as 44 | preceding comments are not sent as a part of this query. 45 | 46 | 47 | ```plpgsql 48 | =# CREATE FUNCTION hints_func(integer) RETURNS integer AS $$ 49 | DECLARE 50 | id integer; 51 | cnt integer; 52 | BEGIN 53 | SELECT /*+ NoIndexScan(a) */ aid 54 | INTO id FROM pgbench_accounts a WHERE aid = $1; 55 | SELECT /*+ SeqScan(a) */ count(*) 56 | INTO cnt FROM pgbench_accounts a; 57 | RETURN id + cnt; 58 | END; 59 | $$ LANGUAGE plpgsql; 60 | ``` 61 | 62 | ## Upper and lower case handling in object names 63 | 64 | Unlike the way PostgreSQL handles object names, `pg_hint_plan` compares bare 65 | object names in hints against the database internal object names in a 66 | case-sensitive manner. Therefore, an object name TBL in a hint matches 67 | only "TBL" in the database and does not match any unquoted names like 68 | TBL, tbl or Tbl. 69 | 70 | ## Escaping special characters in object names 71 | 72 | The objects defined in a hint's parameter can use double quotes if they 73 | include parentheses, double quotes and white spaces. The escaping rules are 74 | the same as PostgreSQL. 75 | 76 | ## Distinction between multiple occurences of a table 77 | 78 | `pg_hint_plan` identifies the target object by using aliases if any. This 79 | behavior is useful to point to a specific occurrence among multiple 80 | occurrences of one table. 81 | 82 | ```sql 83 | =# /*+ HashJoin(t1 t1) */ 84 | EXPLAIN SELECT * FROM s1.t1 85 | JOIN public.t1 ON (s1.t1.id=public.t1.id); 86 | INFO: hint syntax error at or near "HashJoin(t1 t1)" 87 | DETAIL: Relation name "t1" is ambiguous. 88 | ... 89 | =# /*+ HashJoin(pt st) */ 90 | EXPLAIN SELECT * FROM s1.t1 st 91 | JOIN public.t1 pt ON (st.id=pt.id); 92 | QUERY PLAN 93 | --------------------------------------------------------------------- 94 | Hash Join (cost=64.00..1112.00 rows=28800 width=8) 95 | Hash Cond: (st.id = pt.id) 96 | -> Seq Scan on t1 st (cost=0.00..34.00 rows=2400 width=4) 97 | -> Hash (cost=34.00..34.00 rows=2400 width=4) 98 | -> Seq Scan on t1 pt (cost=0.00..34.00 rows=2400 width=4) 99 | ``` 100 | 101 | ## Underlying tables of views or rules 102 | 103 | Hints are not applicable on views, but they can affect the queries within the 104 | view if the object names match the names in the expanded query on the view. 105 | Assigning aliases to the tables in a view enables them to be manipulated 106 | from outside the view. 107 | 108 | ```sql 109 | =# CREATE VIEW v1 AS SELECT * FROM t2; 110 | =# EXPLAIN /*+ HashJoin(t1 v1) */ 111 | SELECT * FROM t1 JOIN v1 ON (c1.a = v1.a); 112 | QUERY PLAN 113 | ------------------------------------------------------------------ 114 | Hash Join (cost=3.27..18181.67 rows=101 width=8) 115 | Hash Cond: (t1.a = t2.a) 116 | -> Seq Scan on t1 (cost=0.00..14427.01 rows=1000101 width=4) 117 | -> Hash (cost=2.01..2.01 rows=101 width=4) 118 | -> Seq Scan on t2 (cost=0.00..2.01 rows=101 width=4) 119 | ``` 120 | 121 | ## Inheritance 122 | 123 | Hints can only point to the parent of an inheritance tree and the hints affect 124 | all the tables in an inheritance tree. Hints pointing directly to inherited 125 | children have no effect. 126 | 127 | ## Hints in multistatements 128 | 129 | One multistatement can have exactly one hint comment and the hint affects all 130 | of the individual statements in the multistatement. 131 | 132 | ## VALUES expressions 133 | 134 | `VALUES` expressions in `FROM` clause are named as `*VALUES*` internally these 135 | can be hinted if it is the only `VALUES` of a query. Two or more `VALUES` 136 | expressions in a query cannot be distinguished by looking at an `EXPLAIN` result, 137 | resulting in ambiguous results: 138 | 139 | ```sql 140 | =# /*+ MergeJoin(*VALUES*_1 *VALUES*) */ 141 | EXPLAIN SELECT * FROM (VALUES (1, 1), (2, 2)) v (a, b) 142 | JOIN (VALUES (1, 5), (2, 8), (3, 4)) w (a, c) ON v.a = w.a; 143 | INFO: pg_hint_plan: hint syntax error at or near "MergeJoin(*VALUES*_1 *VALUES*) " 144 | DETAIL: Relation name "*VALUES*" is ambiguous. 145 | QUERY PLAN 146 | ------------------------------------------------------------------------- 147 | Hash Join (cost=0.05..0.12 rows=2 width=16) 148 | Hash Cond: ("*VALUES*_1".column1 = "*VALUES*".column1) 149 | -> Values Scan on "*VALUES*_1" (cost=0.00..0.04 rows=3 width=8) 150 | -> Hash (cost=0.03..0.03 rows=2 width=8) 151 | -> Values Scan on "*VALUES*" (cost=0.00..0.03 rows=2 width=8) 152 | ``` 153 | 154 | ## Subqueries 155 | 156 | Subqueries context can be occasionally hinted using the name `ANY_subquery`: 157 | 158 | IN (SELECT ... {LIMIT | OFFSET ...} ...) 159 | = ANY (SELECT ... {LIMIT | OFFSET ...} ...) 160 | = SOME (SELECT ... {LIMIT | OFFSET ...} ...) 161 | 162 | For these syntaxes, the planner internally assigns the name to the subquery 163 | when planning joins on tables including it, so join hints are applicable on 164 | such joins using the implicit name. For example: 165 | 166 | ```sql 167 | =# /*+HashJoin(a1 ANY_subquery)*/ 168 | EXPLAIN SELECT * 169 | FROM pgbench_accounts a1 170 | WHERE aid IN (SELECT bid FROM pgbench_accounts a2 LIMIT 10); 171 | QUERY PLAN 172 | 173 | --------------------------------------------------------------------------------------------- 174 | Hash Semi Join (cost=0.49..2903.00 rows=1 width=97) 175 | Hash Cond: (a1.aid = a2.bid) 176 | -> Seq Scan on pgbench_accounts a1 (cost=0.00..2640.00 rows=100000 width=97) 177 | -> Hash (cost=0.36..0.36 rows=10 width=4) 178 | -> Limit (cost=0.00..0.26 rows=10 width=4) 179 | -> Seq Scan on pgbench_accounts a2 (cost=0.00..2640.00 rows=100000 width=4) 180 | ``` 181 | 182 | ## Using `IndexOnlyScan` hint 183 | 184 | Index scan may be unexpectedly performed on another index when the index 185 | specified in IndexOnlyScan hint cannot perform an index only scan. 186 | 187 | ## About `NoIndexScan` 188 | 189 | A `NoIndexScan` hint implies `NoIndexOnlyScan`. 190 | 191 | ## Parallel hints and `UNION` 192 | 193 | A `UNION` can run in parallel only when all underlying subqueries are 194 | parallel-safe. Hence, enforcing parallel on any of the subqueries will let a 195 | parallel-executable `UNION` run in parallel. Meanwhile, a parallel hint with 196 | zero workers prevents a scan from being executed in parallel. 197 | 198 | ## Setting `pg_hint_plan` parameters by Set hints 199 | 200 | `pg_hint_plan` parameters influence their own behavior so some parameters 201 | will not work as one could expect: 202 | 203 | - Hints to change `enable_hint`, `enable_hint_table` are ignored even though 204 | they are reported as "used hints" in debug logs. 205 | - Setting `debug_print` and `message_level` in the middle of query processing. 206 | -------------------------------------------------------------------------------- /docs/hint_list.md: -------------------------------------------------------------------------------- 1 | (hint-list)= 2 | # Hint list 3 | 4 | The available hints are listed below. 5 | 6 | | Group | Format | Description | 7 | |:------|:-------|:------------| 8 | | Scan method | `SeqScan(table)`| Forces sequential scan on the table. | 9 | | | `TidScan(table)` | Forces TID scan on the table. | 10 | | | `IndexScan(table[ index...])` | Forces index scan on the table. Restricts to specified indexes if any. | 11 | | | `IndexOnlyScan(table[ index...])` | Forces index-only scan on the table. Restricts to specified indexes if any. Index scan may be used if index-only scan is not available. | 12 | | | `BitmapScan(table[ index...])`| Forces bitmap scan on the table. Restricts to specified indexes if any. | 13 | | | `IndexScanRegexp(table[ POSIX Regexp...])`
`IndexOnlyScanRegexp(table[ POSIX Regexp...])`
`BitmapScanRegexp(table[ POSIX Regexp...])` | Forces index scan, index-only scan (For PostgreSQL 9.2 and later) or bitmap scan on the table. Restricts to indexes that matches the specified POSIX regular expression pattern. | 14 | | | `NoSeqScan(table)`| Forces to *not* do sequential scan on the table. | 15 | | | `NoTidScan(table)`| Forces to *not* do TID scan on the table.| 16 | | | `NoIndexScan(table)`| Forces to *not* do index scan and index-only scan on the table. | 17 | | | `NoIndexOnlyScan(table)`| Forces to *not* do index only scan on the table. | 18 | | | `NoBitmapScan(table)` | Forces to *not* do bitmap scan on the table. | 19 | | Join method| `NestLoop(table table[ table...])` | Forces nested loop for the joins on the tables specified. | 20 | | | `HashJoin(table table[ table...])`| Forces hash join for the joins on the tables specified. | 21 | | | `MergeJoin(table table[ table...])` | Forces merge join for the joins on the tables specified. | 22 | | | `NoNestLoop(table table[ table...])`| Forces to *not* do nested loop for the joins on the tables specified. | 23 | | | `NoHashJoin(table table[ table...])`| Forces to *not* do hash join for the joins on the tables specified. | 24 | | | `NoMergeJoin(table table[ table...])` | Forces to *not* do merge join for the joins on the tables specified. | 25 | | Join order | `Leading(table table[ table...])` | Forces join order as specified. | 26 | | | `Leading()`| Forces join order and directions as specified. A join pair is a pair of tables and/or other join pairs enclosed by parentheses, which can make a nested structure. | 27 | | Behavior control on Join | `Memoize(table table[ table...])` | Allows the topmost join of a join among the specified tables to Memoize the inner result. Not enforced. | 28 | | | `NoMemoize(table table[ table...])` | Inhibits the topmost join of a join among the specified tables from Memoizing the inner result. | 29 | | Row number correction | `Rows(table table[ table...] correction)` | Corrects row number of a result of the joins on the tables specified. The available correction methods are absolute (#), addition (+), subtract (-) and multiplication (*). should be a string that strtod() can understand. | 30 | | Parallel query configuration | `Parallel(table <# of workers> [soft\|hard])` | Enforces or inhibits parallel execution of the specified table. <# of workers> is the desired number of parallel workers, where zero means inhibiting parallel execution. If the third parameter is soft (default), it just changes max\_parallel\_workers\_per\_gather and leaves everything else to the planner. Hard enforces the specified number of workers. | 31 | | GUC | `Set(GUC-param value)` | Sets GUC parameter to the value defined while planner is running. | 32 | -------------------------------------------------------------------------------- /docs/hint_table.md: -------------------------------------------------------------------------------- 1 | # The hint table 2 | 3 | Hints can be specified in a comment, still this can be inconvenient in the case 4 | where queries cannot be edited. In the case, hints can be placed in a special 5 | table named `"hint_plan.hints"`. The table consists of the following columns: 6 | 7 | | column | description | 8 | |:-------|:------------| 9 | | `id` | Unique number to identify a row for a hint.
This column is filled automatically by sequence. | 10 | | `query_id` | A unique query ID, generated by the backend when the GUC compute_query_id is enabled | 11 | | `application_name` | The value of `application_name` where sessions can apply a hint.
The hint in the example below applies to sessions connected from psql.
An empty string implies that all sessions will apply the hint. | 12 | | `hints` | Hint phrase.
This must be a series of hints excluding surrounding comment marks. | 13 | 14 | The following example shows how to operate with the hint table. 15 | 16 | ```sql 17 | =# EXPLAIN (VERBOSE, COSTS false) SELECT * FROM t1 WHERE t1.id = 1; 18 | QUERY PLAN 19 | ---------------------------------------- 20 | Seq Scan on public.t1 21 | Output: id, id2 22 | Filter: (t1.id = 1) 23 | Query Identifier: -7164653396197960701 24 | (4 rows) 25 | =# INSERT INTO hint_plan.hints(query_id, application_name, hints) 26 | VALUES (-7164653396197960701, '', 'SeqScan(t1)'); 27 | INSERT 0 1 28 | =# UPDATE hint_plan.hints 29 | SET hints = 'IndexScan(t1)' 30 | WHERE id = 1; 31 | UPDATE 1 32 | =# DELETE FROM hint_plan.hints WHERE id = 1; 33 | DELETE 1 34 | ``` 35 | 36 | The hint table is owned by the extension owner and has the same default 37 | privileges as of the time of its creation, during `CREATE EXTENSION`. 38 | Hints in the hint table are prioritized over hints in comments. 39 | 40 | The query ID can be retrieved with `pg_stat_statements` or with 41 | `EXPLAIN (VERBOSE)`. 42 | 43 | ## Types of hints 44 | 45 | Hinting phrases are classified in multiple types based on what kind of object 46 | and how they can affect the planner. See [Hint list](#hint-list) for more 47 | details. 48 | 49 | ### Hints for Scan methods 50 | 51 | Scan method hints enforce specific scanning methods on the target table. 52 | `pg_hint_plan` recognizes the target table by alias names if any. These are 53 | for example `SeqScan` or `IndexScan`. 54 | 55 | Scan hints work on ordinary tables, inheritance tables, UNLOGGED tables, 56 | temporary tables and system catalogs. External (foreign) tables, table 57 | functions, VALUES clause, CTEs, views and subqueries are not affected. 58 | 59 | ```sql 60 | =# /*+ 61 | SeqScan(t1) 62 | IndexScan(t2 t2_pkey) 63 | */ 64 | SELECT * FROM table1 t1 JOIN table table2 t2 ON (t1.key = t2.key); 65 | ``` 66 | 67 | ### Hints for Join methods 68 | 69 | Join method hints enforce the join methods of the joins involving the 70 | specified tables. 71 | 72 | This can affect joins only on ordinary tables. Inheritance tables, UNLOGGED 73 | tables, temporary tables, external (foreign) tables, system catalogs, table 74 | functions, VALUES command results and CTEs are allowed to be in the parameter 75 | list. Joins on views and subqueries are not affected. 76 | 77 | ### Hints for Joining order 78 | 79 | This hint, named "Leading", enforces the order of join on two or more tables. 80 | There are two methods of enforcing it. The first method enforces a specific 81 | order of joining but does not restrict the direction at each join level. 82 | The second method enforces the join direction additionally. See 83 | [hint list](#hint-list) for more details. For example: 84 | 85 | ```sql 86 | =# /*+ 87 | NestLoop(t1 t2) 88 | MergeJoin(t1 t2 t3) 89 | Leading(t1 t2 t3) 90 | */ 91 | SELECT * FROM table1 t1 92 | JOIN table table2 t2 ON (t1.key = t2.key) 93 | JOIN table table3 t3 ON (t2.key = t3.key); 94 | ``` 95 | 96 | ### Hints for Row number corrections 97 | 98 | This hint, named "Rows", changes the row number estimation of joins that comes 99 | from restrictions in the planner. For example: 100 | 101 | ```sql 102 | =# /*+ Rows(a b #10) */ SELECT... ; Sets rows of join result to 10 103 | =# /*+ Rows(a b +10) */ SELECT... ; Increments row number by 10 104 | =# /*+ Rows(a b -10) */ SELECT... ; Subtracts 10 from the row number. 105 | =# /*+ Rows(a b *10) */ SELECT... ; Makes the number 10 times larger. 106 | ``` 107 | 108 | ### Hints for parallel plans 109 | 110 | This hint, named `Parallel`, enforces parallel execution configuration 111 | on scans. The third parameter specifies the strength of the enforcement. 112 | `soft` means that `pg_hint_plan` only changes `max_parallel_worker_per_gather` 113 | and leaves all the others to the planner to set. `hard` changes other planner 114 | parameters so as to forcibly apply the update. This can affect ordinary 115 | tables, inheritance parents, unlogged tables and system catalogs. External 116 | tables, table functions, `VALUES` clauses, CTEs, views and subqueries are 117 | not affected. Internal tables of a view can be specified by its real 118 | name or its alias as the target object. The following example shows 119 | that the query is enforced differently on each table: 120 | 121 | ```sql 122 | =# EXPLAIN /*+ Parallel(c1 3 hard) Parallel(c2 5 hard) */ 123 | SELECT c2.a FROM c1 JOIN c2 ON (c1.a = c2.a); 124 | QUERY PLAN 125 | ------------------------------------------------------------------------------- 126 | Hash Join (cost=2.86..11406.38 rows=101 width=4) 127 | Hash Cond: (c1.a = c2.a) 128 | -> Gather (cost=0.00..7652.13 rows=1000101 width=4) 129 | Workers Planned: 3 130 | -> Parallel Seq Scan on c1 (cost=0.00..7652.13 rows=322613 width=4) 131 | -> Hash (cost=1.59..1.59 rows=101 width=4) 132 | -> Gather (cost=0.00..1.59 rows=101 width=4) 133 | Workers Planned: 5 134 | -> Parallel Seq Scan on c2 (cost=0.00..1.59 rows=59 width=4) 135 | 136 | =# EXPLAIN /*+ Parallel(tl 5 hard) */ SELECT sum(a) FROM tl; 137 | QUERY PLAN 138 | ----------------------------------------------------------------------------------- 139 | Finalize Aggregate (cost=693.02..693.03 rows=1 width=8) 140 | -> Gather (cost=693.00..693.01 rows=5 width=8) 141 | Workers Planned: 5 142 | -> Partial Aggregate (cost=693.00..693.01 rows=1 width=8) 143 | -> Parallel Seq Scan on tl (cost=0.00..643.00 rows=20000 width=4) 144 | ``` 145 | 146 | ### GUC parameters set during planning 147 | 148 | `Set` hints change GUC parameters just while planning. GUC parameter shown in 149 | [Query Planning](http://www.postgresql.org/docs/current/static/runtime-config-query.html) 150 | can have the expected effects on planning unless an other hint conflicts with 151 | the planner method configuration parameters. When multiple hints change the 152 | same GUC, the last hint takes effect. 153 | [GUC parameters for `pg_hint_plan`](#guc-parameters-for-pg_hint_plan) are also 154 | settable by this hint but it may not work as expected. 155 | See [Functional limitations](#functional-limitations) for details. 156 | 157 | ```sql 158 | =# /*+ Set(random_page_cost 2.0) */ 159 | SELECT * FROM table1 t1 WHERE key = 'value'; 160 | ... 161 | ``` 162 | 163 | (guc-parameters-for-pg_hint_plan)= 164 | ## GUC parameters for `pg_hint_plan` 165 | 166 | The following GUC parameters affect the behavior of `pg_hint_plan`: 167 | 168 | | Parameter name | Description | Default | 169 | |:---------------|:------------|:--------| 170 | | `pg_hint_plan.enable_hint` | True enables `pg_hint_plan`. | `on` | 171 | | `pg_hint_plan.enable_hint_table` | True enables hinting by table. | `off` | 172 | | `pg_hint_plan.parse_messages` | Specifies the log level of hint parse error. Valid values are `error`, `warning`, `notice`, `info`, `log`, `debug`. | `INFO` | 173 | | `pg_hint_plan.debug_print` | Controls debug print and verbosity. Valid values are `off`, `on`, `detailed` and `verbose`. | `off` | 174 | | `pg_hint_plan.message_level` | Specifies message level of debug print. Valid values are `error`, `warning`, `notice`, `info`, `log`, `debug`. | `INFO` | 175 | -------------------------------------------------------------------------------- /docs/index.md: -------------------------------------------------------------------------------- 1 | # pg_hint_plan 1.8 2 | 3 | ```{contents} Table of Contents 4 | :depth: 2 5 | ``` 6 | 7 | ```{toctree} 8 | synopsis.md 9 | description.md 10 | hint_table.md 11 | installation.md 12 | uninstallation.md 13 | hint_details.md 14 | errors.md 15 | functional_limitations.md 16 | requirements.md 17 | hint_list.md 18 | ``` 19 | -------------------------------------------------------------------------------- /docs/installation.md: -------------------------------------------------------------------------------- 1 | # Installation 2 | 3 | This section describes the installation steps. 4 | 5 | ## Building binary module 6 | 7 | Simply run `make` at the top of the source tree, then `make install` as an 8 | appropriate user. The `PATH` environment variable should be set properly 9 | to point to a PostgreSQL set of binaries: 10 | 11 | $ tar xzvf pg_hint_plan-1.x.x.tar.gz 12 | $ cd pg_hint_plan-1.x.x 13 | $ make 14 | $ su 15 | $ make install 16 | 17 | ## Installing from a binary package 18 | 19 | On Debian and Ubuntu `pg_hint_plan` is available as a binary package from the 20 | pgdg (PostgreSQL Global Development Group) repository. Assuming you've 21 | already added the repository to `apt` sources, installing the package is as 22 | simple as: 23 | 24 | ``` 25 | sudo apt install postgresql--pg-hint-plan 26 | ``` 27 | 28 | Please visit https://www.postgresql.org/download/linux/ if you need help at 29 | adding the repository. 30 | 31 | ## Loading `pg_hint_plan` 32 | 33 | `pg_hint_plan` does not require `CREATE EXTENSION`. Loading it with a `LOAD` 34 | command will activate it and of course you can load it globally by setting 35 | `shared_preload_libraries` in `postgresql.conf`. Or you might be 36 | interested in `ALTER USER SET`/`ALTER DATABASE SET` for automatic loading in 37 | specific sessions. 38 | 39 | ```sql 40 | postgres=# LOAD 'pg_hint_plan'; 41 | LOAD 42 | ``` 43 | 44 | Run `CREATE EXTENSION` and `SET pg_hint_plan.enable_hint_table TO on` if you 45 | are planning to use the hint table. 46 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/description.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan description. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-09 15:31+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../description.md:1 0082a55147374c7ab16faf346b5cde78 25 | msgid "Description" 26 | msgstr "機能説明" 27 | 28 | #: ../../description.md:3 a578f7e648784224aa5562b6c0859fe0 29 | msgid "Basic Usage" 30 | msgstr "基本的な使用方法" 31 | 32 | #: ../../description.md:5 3b1114e41a8e4a9a88e435ba40b8ed46 33 | msgid "" 34 | "`pg_hint_plan` reads hinting phrases in a comment of special form given " 35 | "a SQL statement. A hint can be specified by prefixing it with the " 36 | "sequence `\"/\\*+\"` and ending it with `\"\\*/\"`. Hint phrases " 37 | "consist of hint names and parameters enclosed by parentheses and " 38 | "delimited by whitespaces. Hint phrases can use newlines for readability." 39 | msgstr "" 40 | "`pg_hint_plan`はSQL文に与えられた特別な形式のコメント内のヒント句を読み取" 41 | "ります。\n" 42 | "ヒントは先頭に `\"/*+\"`というシーケンスを付け、最後に `\"*/\"` を付ける" 43 | "ことで指定できます。\n" 44 | "ヒント句はヒント名とそれに続くパラメータを括弧で囲み、スペースで区切った" 45 | "ものです。\n" 46 | "ヒント句は読みやすくするために改行することができます。" 47 | 48 | #: ../../description.md:11 4bf58e34acd743419ea82b29b6e2f6fb 49 | msgid "" 50 | "In the example below, a hash join is selected as the join method while " 51 | "doing a sequential scan on `pgbench_accounts`:" 52 | msgstr "" 53 | "以下の例では、`pgbench_accounts` に対してシーケンシャルスキャンを行う際に" 54 | "結合方法としてハッシュ結合が選択されています。" 55 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/errors.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan errors. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-09 15:48+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../errors.md:1 7bb59eaf638542abb9586f050733a4e0 25 | msgid "Errors" 26 | msgstr "エラー" 27 | 28 | #: ../../errors.md:3 e3db83c556504b0abfe85134459031bc 29 | msgid "`pg_hint_plan` stops hint parsing on any error and will uses the hints already parsed. Here are some typical errors." 30 | msgstr "`pg_hint_plan`はエラーが発生するとヒントの構文解析を停止し、既に構文解析されたヒントを使用します。以下は典型的なエラーです。" 31 | 32 | #: ../../errors.md:6 a8760d36d17f470ab6afbbb02c1ff219 33 | msgid "Syntax errors" 34 | msgstr "シンタックスエラー" 35 | 36 | #: ../../errors.md:8 b1414efb066a4ddfbad0ce8cbe16fb58 37 | msgid "" 38 | "Any syntactical errors or wrong hint names are reported as a syntax error. These errors are reported in the server log with the message level " 39 | "specified by `pg_hint_plan.message_level` if `pg_hint_plan.debug_print` is on and above." 40 | msgstr "" 41 | "構文的なエラーやヒント名の誤りなどはシンタックスエラーとして出力されます。これらのエラーは`pg_hint_plan.debug_print`がON以上の場合、`pg_hint_plan." 42 | "message_level`によって指定されたメッセージレベルでサーバログに出力されます。" 43 | 44 | #: ../../errors.md:13 d28f5080cc7e41acabc18494d6ac768a 45 | msgid "Incorrect Object definitions" 46 | msgstr "誤ったオブジェクトの指定" 47 | 48 | #: ../../errors.md:15 1643ff73330f44eea56fd6babeb8a4e4 49 | msgid "" 50 | "Incorrect object definitions result in silently ignoring the hints. This kind of error is reported as a \"Not Used Hint\" in the server logs." 51 | msgstr "" 52 | "オブジェクトの指定に誤りがあるとヒントは無言で無視されます。この種類のエラーはシンタックスエラーと同様の条件で \"Not used hints\" としてサーバログ" 53 | "に出力されます。" 54 | 55 | #: ../../errors.md:18 da03af4bd07e450c952f8f8c471d9f71 56 | msgid "Redundant or conflicting hints" 57 | msgstr "冗長または競合するヒント" 58 | 59 | #: ../../errors.md:20 833a65ab64b043c08b4cb3aaf687272a 60 | msgid "" 61 | "The last hint is considered when redundant hints are defined or hints conflict with each other. This kind of error is reported as a duplicated " 62 | "hints." 63 | msgstr "" 64 | "冗長なヒントが指定されている場合やヒント同士が競合している場合は、最後のヒントが考慮されます。この種類のエラーは \"duplication hints\" として報告" 65 | "されます。" 66 | 67 | #: ../../errors.md:24 f3374244abe74052b9814e28cbe98045 68 | msgid "Nested comments" 69 | msgstr "ネストされたコメント" 70 | 71 | #: ../../errors.md:26 020914d49a2d42b28d82f4fd898d99dc 72 | msgid "Hint comments cannot be recursive. If detected, hint parsing is immediately stopped and all the hints already parsed are ignored." 73 | msgstr "ヒントコメントは再帰的に使用できません。 検出された場合、ヒントの構文解析は直ちに停止され、既に解析されたヒントはすべて無視されます。" 74 | 75 | #~ msgid "Object misspecifications" 76 | #~ msgstr "オブジェクトの指定誤り" 77 | 78 | #~ msgid "" 79 | #~ "Hint comment cannot include another block comment within. If `pg_hint_plan` finds it, differently from other erros, it stops parsing and " 80 | #~ "abandans all hints already parsed. This kind of error is reported in the same manner as other errors." 81 | #~ msgstr "" 82 | #~ "コメントヒント内に別のブロックコメントを含めることはできません。`pg_hint_plan` はそれを見つけた場合、他のエラーとは異なり構文解析を中止し、既に" 83 | #~ "構文解析された全てのヒントを破棄します。この種類のエラーは他のエラーと同様の方法で出力されます。" 84 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/functional_limitations.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan functional limitations. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-09 16:11+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../functional_limitations.md:3 da6339603ee44e339854438c56df1a29 25 | msgid "Functional limitations" 26 | msgstr "機能的な制限事項" 27 | 28 | #: ../../functional_limitations.md:5 be4f92a4dd7d47a989ba1c69bd77adc3 29 | msgid "Influence of planner GUC parameters" 30 | msgstr "プランナGUCパラメータの影響" 31 | 32 | #: ../../functional_limitations.md:7 dafb3bc544094d148e90be5939598bd3 33 | msgid "" 34 | "The planner does not try to consider joining order for FROM clause entries more than `from_collapse_limit`. `pg_hint_plan` cannot affect the " 35 | "joining order in this case." 36 | msgstr "" 37 | "プランナは、`from_collapse_limit`を超えるFROM句の項目に対する結合順を考慮しようとしません。`pg_hint_plan`は、このケースに対して期待される結合順" 38 | "に影響を与えることはできません。" 39 | 40 | #: ../../functional_limitations.md:11 70edb32d7f0440fabb314c610a8fc821 41 | msgid "Hints trying to enforce non-executable plans" 42 | msgstr "実行不可能なプランの強制を試みるヒント" 43 | 44 | #: ../../functional_limitations.md:13 9ed907c72c54444eb44b2b882bd60dd4 45 | msgid "Planner chooses any executable plans when the enforced plan cannot be executed:" 46 | msgstr "強制されたプランが実行できない場合、プランナは任意の実行可能なプランを選択します。" 47 | 48 | #: ../../functional_limitations.md:16 1c5bd7e76aee488ba18b424cc4c88a7d 49 | msgid "`FULL OUTER JOIN` to use nested loop." 50 | msgstr "・`FULL OUTER JOIN`をnested loopで使用" 51 | 52 | #: ../../functional_limitations.md:17 e9d031ec2aef47f2bfdd0c757524e18b 53 | msgid "Use of indexes that do not have columns used in quals." 54 | msgstr "・条件式で使用されるカラムを持っていないインデックスを使用" 55 | 56 | #: ../../functional_limitations.md:18 ec237007987748a3995e437a575c74bc 57 | msgid "TID scans for queries without ctid conditions." 58 | msgstr "・ctid条件が無いクエリに対するTIDスキャンの実行" 59 | 60 | #: ../../functional_limitations.md:20 87dad13bf42a42d599747de3bb2750f3 61 | msgid "Queries in ECPG" 62 | msgstr "ECPG内のクエリ" 63 | 64 | #: ../../functional_limitations.md:22 28551eee47744d1eb740fbd1842d57a5 65 | msgid "" 66 | "ECPG removes comments in queries written as embedded SQLs so hints cannot be passed to it. The only exception `EXECUTE`, that passes the " 67 | "query string to the server as-is. The hint table can be used in the case." 68 | msgstr "" 69 | "ECPGは埋め込みSQLとして書かれたクエリのコメントを削除するのでヒントを渡すことはできません。唯一の例外は`EXECUTE`で、これはクエリ文字列をそのま" 70 | "まサーバに渡します。このようなケースにおいてはヒントテーブルを利用することができます。" 71 | 72 | #: ../../functional_limitations.md:26 b06f1bb15ae142c3bc3b53165fe6ac94 73 | msgid "`pg_stat_statements`" 74 | msgstr "`pg_stat_statements`との連携" 75 | 76 | #: ../../functional_limitations.md:28 a5024f97919e463f9d5cf05307f060aa 77 | msgid "" 78 | "`pg_stat_statements` generates a query ID, ignoring comments. Hence, queries with different hints, still written the same way, may compute " 79 | "the same query ID." 80 | msgstr "" 81 | "`pg_stat_statements`はコメントを無視したクエリIDを生成します。その結果、異なるヒントを持つクエリでも同じように書かれたものであれば、同一のクエ" 82 | "リIDが計算されます。" 83 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/hint_details.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan hint details. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-09 17:14+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../hint_details.md:1 3916d6f4fefb4860a66e64185a367ccb 25 | msgid "Details in hinting" 26 | msgstr "ヒントの詳細" 27 | 28 | #: ../../hint_details.md:3 43655c2ef5724d0e93c25c7e48e6d7e4 29 | msgid "Syntax and placement" 30 | msgstr "構文と配置" 31 | 32 | #: ../../hint_details.md:5 ecc0a0a7b5bc46aab04288ee505c9bc6 33 | msgid "" 34 | "`pg_hint_plan` reads hints from only the first block comment and stops parsing from any characters except alphabetical characters, digits, spaces, underscores, commas and " 35 | "parentheses. In the following example, `HashJoin(a b)` and `SeqScan(a)` are parsed as hints, but `IndexScan(a)` and `MergeJoin(a b)` are not:" 36 | msgstr "" 37 | "`pg_hint_plan`は最初のブロックコメントのみからヒントを読み、アルファベット、数字、スペース、アンダースコア、カンマ、括弧の文字以外は構文解析を停止します。以下の例では、" 38 | "`HashJoin(a b)`と`SeqScan(a)`はヒントとして構文解析されますが、`IndexScan(a)`と`MergeJoin(a b)`はヒントとして構文解析されません。" 39 | 40 | #: ../../hint_details.md:33 78eab7010cc1455baa2f205249d93c97 41 | msgid "Using with PL/pgSQL" 42 | msgstr "PL/pgSQLでの使用" 43 | 44 | #: ../../hint_details.md:35 5dbec72f377c4092920c8799940f5b65 45 | msgid "`pg_hint_plan` works for queries in PL/pgSQL scripts with some restrictions." 46 | msgstr "`pg_hint_plan`はPL/pgSQLスクリプト内のクエリに対してはいくつかの制限付きで動作します。" 47 | 48 | #: ../../hint_details.md:37 f64f8753c136462c878649370469b4e2 49 | msgid "Hints affect only on the following kind of queries:" 50 | msgstr "ヒントは以下のような種類のクエリにのみ影響します。" 51 | 52 | #: ../../hint_details.md:38 f7a66dc08f124076949354fe230230f2 53 | msgid "Queries that returns one row (`SELECT`, `INSERT`, `UPDATE` and `DELETE`)" 54 | msgstr "・1行を返すクエリ (`SELECT`、`INSERT`、`UPDATE`、`DELETE`)" 55 | 56 | #: ../../hint_details.md:39 b65d3ed0c2d34be3ad3a55447c392a0f 57 | msgid "Queries that returns multiple rows (`RETURN QUERY`)" 58 | msgstr "・複数行を返すクエリ (`RETURNクエリ`)" 59 | 60 | #: ../../hint_details.md:40 354c7d320fd04c1d85fa38deb1c1c852 61 | msgid "Dynamic SQL statements (`EXECUTE`)" 62 | msgstr "・動的なSQL文 (`EXECUTE`)" 63 | 64 | #: ../../hint_details.md:41 d32faee862b24e5a9f98ffb2035d055a 65 | msgid "Cursor open (`OPEN`)" 66 | msgstr "・カーソルを開く (`OPEN`)" 67 | 68 | #: ../../hint_details.md:42 acc9d1e9c55547f8a47dc55eaa56074b 69 | msgid "Loop over result of a query (`FOR`)" 70 | msgstr "・クエリの結果をループ (`FOR`)" 71 | 72 | #: ../../hint_details.md:43 411605b0c4134ba387581401454cba04 73 | msgid "A hint comment has to be placed after the first word in a query as preceding comments are not sent as a part of this query." 74 | msgstr "ヒントコメントは次のようにクエリの最初の単語の後に配置する必要があります。クエリよりも先行するコメントはクエリの一部として送信されません。" 75 | 76 | #: ../../hint_details.md:62 0d4da03aad854e46a74c2f3c63bd5a43 77 | msgid "Upper and lower case handling in object names" 78 | msgstr "オブジェクト名の大文字と小文字の区別" 79 | 80 | #: ../../hint_details.md:64 a77063b0badd4fbcaaba9f744f6061b4 81 | msgid "" 82 | "Unlike the way PostgreSQL handles object names, `pg_hint_plan` compares bare object names in hints against the database internal object names in a case-sensitive manner. " 83 | "Therefore, an object name TBL in a hint matches only \"TBL\" in the database and does not match any unquoted names like TBL, tbl or Tbl." 84 | msgstr "" 85 | "PostgreSQLがオブジェクト名を扱う方法とは異なり、`pg_hint_plan`はヒントに含まれるオブジェクト名とデータベース内部のオブジェクト名を大文字・小文字を区別して比較します。したがっ" 86 | "て、ヒント内のオブジェクト名TBLはデータベース内の \"TBL \"にのみマッチし、TBL、tbl、Tblのような引用符のない名前にはマッチしません。" 87 | 88 | #: ../../hint_details.md:70 b0976ff1156d4bc9a5736e0bfdfd5af9 89 | msgid "Escaping special characters in object names" 90 | msgstr "オブジェクト名の特殊文字のエスケープ" 91 | 92 | #: ../../hint_details.md:72 608bacd6b49247f3a4fa2bb83b2c265e 93 | msgid "" 94 | "The objects defined in a hint's parameter can use double quotes if they includes parentheses, double quotes and white spaces. The escaping rules are the same as PostgreSQL." 95 | msgstr "ヒントのパラメータに指定されたオブジェクト名に括弧、二重引用符、空白を含む場合、二重引用符で囲む必要があります。エスケープのルールはPostgreSQLと同じです。" 96 | 97 | #: ../../hint_details.md:76 810a3d2f9751400bafc22232c9ce282d 98 | msgid "Distinction between multiple occurences of a table" 99 | msgstr "複数出現するテーブルの区別" 100 | 101 | #: ../../hint_details.md:78 0fca65236cdd4526ad71b47ab51d4fad 102 | msgid "`pg_hint_plan` identifies the target object by using aliases if any. This behavior is useful to point to a specific occurrence among multiple occurrences of one table." 103 | msgstr "`pg_hint_plan`は別名が存在する場合、それを使用して対象オブジェクトを特定します。この動作は、1つのテーブルが複数出現する中から特定のものを指定するのに便利です。" 104 | 105 | #: ../../hint_details.md:101 c4605f5739804aa9a09e1b29281ed988 106 | msgid "Underlying tables of views or rules" 107 | msgstr "ビューまたはルールの根底にあるテーブル" 108 | 109 | #: ../../hint_details.md:103 6cc71dd6ed69461d98b6d54b2e2dd275 110 | msgid "" 111 | "Hints are not applicable on views, but they can affect the queries within the view if the object names match the names in the expanded query on the view. Assigning aliases to " 112 | "the tables in a view enables them to be manipulated from outside the view." 113 | msgstr "" 114 | "ヒントはビュー自体には適用されませんが、オブジェクト名がビュー上に展開されたクエリ内のオブジェクト名と一致する場合、ビュー内のクエリに影響を与えることができます。ビュー内のテー" 115 | "ブルに別名を割り当てると、ビューの外からそれらを操作することができます。" 116 | 117 | #: ../../hint_details.md:121 10d1034f3ff14a67b984da7c7010a4f7 118 | msgid "Inheritance" 119 | msgstr "継承" 120 | 121 | #: ../../hint_details.md:123 8869b00244e84a9e8872273988a67faa 122 | msgid "" 123 | "Hints can only point to the parent of an inheritance tree and the hint saffect all the tables in an inheritance tree. Hints pointing directly to inherited children have no " 124 | "effect." 125 | msgstr "ヒントは継承ツリーの親だけを指すことができ、そのヒントはすべての継承ツリーに影響します。継承された子を直接指定するヒントは無効です。" 126 | 127 | #: ../../hint_details.md:127 8096d191cb5e474e9a5fd2f2f272dc4c 128 | msgid "Hints in multistatements" 129 | msgstr "マルチステートメントでのヒント" 130 | 131 | #: ../../hint_details.md:129 996708ffa9524ae3bcc7c1de1f104a66 132 | msgid "One multistatement can have exactly one hint comment and the hint affects all of the individual statements in the multistatement." 133 | msgstr "1つのマルチステートメントに1つのヒントコメントを指定することができ、そのヒントはマルチステートメント内のすべてのステートメントに影響します。" 134 | 135 | #: ../../hint_details.md:132 90f90d5ae8f3470c83fe8882fbe8b331 136 | msgid "VALUES expressions" 137 | msgstr "VALUES式" 138 | 139 | #: ../../hint_details.md:134 3132d53228064192a59cacaf625c9b7b 140 | msgid "" 141 | "`VALUES` expressions in `FROM` clause are named as `*VALUES*` internally these can be hinted if it is the only `VALUES` of a query. Two or more `VALUES` expressions in a " 142 | "query cannot be distinguised by looking at an `EXPLAIN` result, resulting in ambiguous results:" 143 | msgstr "" 144 | "`FROM`句の`VALUES`式は、内部的には`*VALUES*`と名付けられ、もしそれがクエリ内の唯一の`VALUES`であればヒントを使用できる可能性があります。2つ以上の`VALUES`式があるクエリは、" 145 | "`EXPLAIN`の結果を見て区別が出来ず、曖昧な結果になります。" 146 | 147 | #: ../../hint_details.md:154 2bf1657954804a428d4b652729bb9144 148 | msgid "Subqueries" 149 | msgstr "副問い合わせ" 150 | 151 | #: ../../hint_details.md:156 6b53944192d7439e93480d8c01a6b73c 152 | msgid "Subqueries context can be occasionally hinted using the name `ANY_subquery`:" 153 | msgstr "サブクエリのコンテキストは`ANY_subquery`という名前を使用しヒントにすることができる場合があります。" 154 | 155 | #: ../../hint_details.md:162 9bd0f412c0364cc49bb310c247906164 156 | msgid "" 157 | "For these syntaxes, the planner internally assigns the name to the subquery when planning joins on tables including it, so join hints are applicable on such joins using the " 158 | "implicit name. For example:" 159 | msgstr "" 160 | "これらの構文では副問い合わせを含むテーブルの結合を計画する際に、プランナは副問い合わせに対し内部的に名前を割り当てます。そのため、結合方法ヒントは暗黙の名前を使用している結合に" 161 | "適用することができます。以下は例です。" 162 | 163 | #: ../../hint_details.md:182 5eb9d43cd19a4efbb8de5017d479f4b7 164 | msgid "Using `IndexOnlyScan` hint" 165 | msgstr "IndexOnlyScanヒントの使用" 166 | 167 | #: ../../hint_details.md:184 e462813943c0497c90b549758fdb1e7b 168 | msgid "Index scan may be unexpectedly performed on another index when the index specified in IndexOnlyScan hint cannot perform an index only scan." 169 | msgstr "IndexOnlyScanヒントで指定されたインデックスでインデックスオンリースキャンを実行できない場合、インデックススキャンは予期せず別のインデックスで実行されることがあります。" 170 | 171 | #: ../../hint_details.md:187 da8f9aec6a7f4155a98a8665b8c48c6f 172 | msgid "About `NoIndexScan`" 173 | msgstr "NoIndexScanについて" 174 | 175 | #: ../../hint_details.md:189 8803c3c045b541cba3b7d977a3023f5c 176 | msgid "A `NoIndexScan` hint implies `NoIndexOnlyScan`." 177 | msgstr "`NoIndexScan`ヒントは`NoIndexOnlyScan`を含んでいます。" 178 | 179 | #: ../../hint_details.md:191 924243ac95d24ce6855736a0abf6f618 180 | msgid "Parallel hints and `UNION`" 181 | msgstr "Parallelヒントと`UNION`" 182 | 183 | #: ../../hint_details.md:193 6d4d35b0dce84cbf8001bab7536c92be 184 | msgid "" 185 | "A `UNION` can run in parallel only when all underlying subqueries are parallel-safe. Hence, enforcing parallel on any of the subqueries will let a parallel-executable `UNION` " 186 | "run in parallel. Meanwhile, a parallel hint with zero workers prevents a scan from being executed in parallel." 187 | msgstr "" 188 | "UNIONが並列に実行できるのは、その下にあるすべてのサブクエリの並列実行が安全である場合のみです。したがってサブクエリのいずれかに並列実行を強制することで、並列実行可能なUNIONが並" 189 | "列で実行されます。一方、ワーカーがゼロのPARALLELヒントはスキャンの並列実行を禁止します。" 190 | 191 | #: ../../hint_details.md:198 54510c2b66b5431a87321b9f95739965 192 | msgid "Setting `pg_hint_plan` parameters by Set hints" 193 | msgstr "Set ヒントによる`pg_hint_plan`のパラメータ設定" 194 | 195 | #: ../../hint_details.md:200 a28084ba45d845ffb6313133a0b7657e 196 | msgid "`pg_hint_plan` parameters influence its own behavior so some parameters will not work as one could expect:" 197 | msgstr "・`pg_hint_plan`のパラメータはそれ自体の動作を変更するため、一部のパラメータは期待通りに動作しません。" 198 | 199 | #: ../../hint_details.md:203 7d7058808ee747c1b5478b216f33c899 200 | msgid "Hints to change `enable_hint`, `enable_hint_table` are ignored even though they are reported as \"used hints\" in debug logs." 201 | msgstr "・`enable_hint`, `enable_hint_table`を変更するヒントは、デバッグログに\"used hints\"として報告されても無視されます。" 202 | 203 | #: ../../hint_details.md:205 8dbe1d92409844ab9c6ad6c370fac651 204 | msgid "Setting `debug_print` and `message_level` in the middle of query processing." 205 | msgstr "・`debug_print`と`message_level`の設定は、対象クエリの処理の途中から動作します。" 206 | 207 | #~ msgid "" 208 | #~ "One multistatement can have exactly one hint comment and the hints affects all of the individual statement in the multistatement. Notice that the seemingly multistatement " 209 | #~ "on the interactive interface of psql is internally a sequence of single statements so hints affects only on the statement just following." 210 | #~ msgstr "" 211 | #~ "1つのマルチステートメントには1つのヒントコメントを含めることができ、ヒントはマルチステートメント内のすべてのステートメントに影響します。psqlの対話型インタフェース上では一見" 212 | #~ "マルチステートメントに見えますが、内部的には単一のステートメントのシーケンスであるため、ヒントは直後のステートメントにのみ影響することに注意してください。" 213 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/hint_list.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan hint list. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-09 17:25+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../hint_list.md:2 c40cade5f7394eff896a1fae64bb3ca2 25 | #, fuzzy 26 | msgid "Hint list" 27 | msgstr "ヒント一覧" 28 | 29 | #: ../../hint_list.md:4 2b0acbfb86334a4fae352628abd1bea2 30 | msgid "The available hints are listed below." 31 | msgstr "使用可能なヒントは以下の通りです。" 32 | 33 | #: ../../hint_list.md f91b7fcf62f34ce88bfc5951b88d2a29 34 | msgid "Group" 35 | msgstr "グループ" 36 | 37 | #: ../../hint_list.md 40323de5ffdc4f9cbf0780ba64efebb0 38 | msgid "Format" 39 | msgstr "書式" 40 | 41 | #: ../../hint_list.md bd08a39ffa394a1485b63af6e23b2cec 42 | msgid "Description" 43 | msgstr "説明" 44 | 45 | #: ../../hint_list.md f4146154e6da45f7b2dc29d6bfd6c6a7 46 | msgid "Scan method" 47 | msgstr "スキャン方法" 48 | 49 | #: ../../hint_list.md b1b3b1a782994cd6b760df17dbafa074 50 | msgid "`SeqScan(table)`" 51 | msgstr "`SeqScan(テーブル)`" 52 | 53 | #: ../../hint_list.md f82f7f55ea184a2c92f5e1e9509e318e 54 | msgid "Forces sequential scan on the table." 55 | msgstr "指定されたテーブルにシーケンシャルスキャンを強制します。" 56 | 57 | #: ../../hint_list.md 145bd514e772470ab1a5924bb6109643 58 | msgid "`TidScan(table)`" 59 | msgstr "`TidScan(テーブル)`" 60 | 61 | #: ../../hint_list.md 958102fdfa3f4971b73b5be989813f43 62 | msgid "Forces TID scan on the table." 63 | msgstr "指定されたテーブルにTid スキャンを強制します。検索条件にctidを指定した場合にのみ有効です。" 64 | 65 | #: ../../hint_list.md e28e42e2bdb14ac1a39c21f22e89f555 66 | msgid "`IndexScan(table[ index...])`" 67 | msgstr "`IndexScan(テーブル[ インデックス...])`" 68 | 69 | #: ../../hint_list.md dfbea9060cff4572954e015184ff0cc1 70 | msgid "Forces index scan on the table. Restricts to specified indexes if any." 71 | msgstr "指定されたテーブルにインデックススキャンを強制します。指定されたインデックスがある場合は、そのインデックスに限定されます。" 72 | 73 | #: ../../hint_list.md 09b256ecb32a4e09b4f34fdd29bde0a1 74 | msgid "`IndexOnlyScan(table[ index...])`" 75 | msgstr "`IndexOnlyScan(テーブル[ インデックス...])`" 76 | 77 | #: ../../hint_list.md 3d25b282381e442aad737d8a240a2278 78 | msgid "Forces index-only scan on the table. Restricts to specified indexes if any. Index scan may be used if index-only scan is not available." 79 | msgstr "" 80 | "指定されたテーブルにインデックスオンリースキャンを強制します。指定されたインデックスがある場合は、そのインデックスに限定されます。インデックスオンリースキャンが利用できない場合、インデッ" 81 | "クススキャンが使用されることがあります。" 82 | 83 | #: ../../hint_list.md ef6a8a2ee1434574a7a97aafc8d17b44 84 | msgid "`BitmapScan(table[ index...])`" 85 | msgstr "`BitmapScan(テーブル[ インデックス...])`" 86 | 87 | #: ../../hint_list.md 00c7618bea744cabb797e8522e9196c3 88 | msgid "Forces bitmap scan on the table. Restricts to specified indexes if any." 89 | msgstr "指定されたテーブルにビットマップスキャンを強制します。指定されたインデックスがある場合は、そのインデックスに限定されます。" 90 | 91 | #: ../../hint_list.md d81cb4f03ae64385bad555f177cdfe00 92 | msgid "`IndexScanRegexp(table[ POSIX Regexp...])`
`IndexOnlyScanRegexp(table[ POSIX Regexp...])`
`BitmapScanRegexp(table[ POSIX Regexp...])`" 93 | msgstr "`IndexScanRegexp(テーブル[ POSIX正規表現...])`
`IndexOnlyScanRegexp(テーブル[ POSIX正規表現...])`
`BitmapScanRegexp(テーブル[ POSIX正規表現...])`" 94 | 95 | #: ../../hint_list.md 5d6890da45c349078f67f070a5ee21da 96 | msgid "Forces index scan, index-only scan (For PostgreSQL 9.2 and later) or bitmap scan on the table. Restricts to indexes that matches the specified POSIX regular expression pattern." 97 | msgstr "" 98 | "指定されたテーブルにインデックススキャン、インデックスオンリースキャン(PostgreSQL 9.2以降)、ビットマップスキャンを強制します。指定されたPOSIX正規表現パターンに一致するインデックスに限定" 99 | "されます。" 100 | 101 | #: ../../hint_list.md c78d46c767ff4c3b9137559cd9926280 102 | msgid "`NoSeqScan(table)`" 103 | msgstr "`NoSeqScan(テーブル)`" 104 | 105 | #: ../../hint_list.md faed61dedefa4e9f9fb9be090e255edc 106 | msgid "Forces to *not* do sequential scan on the table." 107 | msgstr "指定されたテーブルにシーケンシャルスキャンを行わないように強制します。" 108 | 109 | #: ../../hint_list.md ab5e0d65a07c448e81ca8e12797df933 110 | msgid "`NoTidScan(table)`" 111 | msgstr "`NoTidScan(テーブル)`" 112 | 113 | #: ../../hint_list.md cd3695b5208f416f92aa6e63e7a14d1b 114 | msgid "Forces to *not* do TID scan on the table." 115 | msgstr "指定されたテーブルにTIDスキャンを行わないように強制します。" 116 | 117 | #: ../../hint_list.md 4f0508bf243c43c383d24734bc3ecb40 118 | msgid "`NoIndexScan(table)`" 119 | msgstr "`NoIndexScan(テーブル)`" 120 | 121 | #: ../../hint_list.md 0809d85d431846c3ba854441fa5e3615 122 | msgid "Forces to *not* do index scan and index-only scan on the table." 123 | msgstr "指定されたテーブルに対してインデックススキャン、インデックスオンリースキャンを行わないように強制します。" 124 | 125 | #: ../../hint_list.md 31f3e92fcd7f4f278cff7305fdc89ec2 126 | msgid "`NoIndexOnlyScan(table)`" 127 | msgstr "`NoIndexOnlyScan(テーブル)`" 128 | 129 | #: ../../hint_list.md 77890cf2fe81441aaa17378e6254ef3b 130 | msgid "Forces to *not* do index only scan on the table." 131 | msgstr "指定されたテーブルにTIDスキャンを行わないように強制します。" 132 | 133 | #: ../../hint_list.md b92575691ae2461fbf89f613acd9ea89 134 | msgid "`NoBitmapScan(table)`" 135 | msgstr "`NoBitmapScan(テーブル)`" 136 | 137 | #: ../../hint_list.md 334171be615a499ca764f9d7331765c6 138 | msgid "Forces to *not* do bitmap scan on the table." 139 | msgstr "指定されたテーブルにビットマップスキャンを行わないように強制します。" 140 | 141 | #: ../../hint_list.md c7a5b8df02cd4727be915878e1ab144e 142 | msgid "Join method" 143 | msgstr "結合方法" 144 | 145 | #: ../../hint_list.md 547262bc8f1a463385eae1c799959982 146 | msgid "`NestLoop(table table[ table...])`" 147 | msgstr "`NestLoop(テーブル テーブル[ テーブル...])`" 148 | 149 | #: ../../hint_list.md 31460cf6de3f4541a0a837bd17c09ecb 150 | msgid "Forces nested loop for the joins on the tables specified." 151 | msgstr "指定されたテーブルで構成された結合にネステッドループ結合を強制します。" 152 | 153 | #: ../../hint_list.md 9488fd678bac48309d7355ebb65c31f7 154 | msgid "`HashJoin(table table[ table...])`" 155 | msgstr "`HashJoin(テーブル テーブル[ テーブル...])`" 156 | 157 | #: ../../hint_list.md 0e5228a6ccb646808507f07171028866 158 | msgid "Forces hash join for the joins on the tables specified." 159 | msgstr "指定されたテーブルで構成された結合にハッシュ結合を強制します。" 160 | 161 | #: ../../hint_list.md 23840bb111534beebb84a9720ef73edf 162 | msgid "`MergeJoin(table table[ table...])`" 163 | msgstr "`MergeJoin(テーブル テーブル[ テーブル...])`" 164 | 165 | #: ../../hint_list.md 922c4b3dee5740feabe8064c3cb0b5fc 166 | msgid "Forces merge join for the joins on the tables specified." 167 | msgstr "指定されたテーブルで構成された結合にマージ結合を強制します。" 168 | 169 | #: ../../hint_list.md 9d74eb0256e345d1ac4401c417403291 170 | msgid "`NoNestLoop(table table[ table...])`" 171 | msgstr "`NoNestLoop(テーブル テーブル[ テーブル...])`" 172 | 173 | #: ../../hint_list.md 9a5dcf745f034721a76969eff89575a2 174 | msgid "Forces to *not* do nested loop for the joins on the tables specified." 175 | msgstr "指定されたテーブルで構成する結合にネステッドループ結合が行われないように強制します。" 176 | 177 | #: ../../hint_list.md c29046a3b4e54453ba444c8fd8d4e26d 178 | msgid "`NoHashJoin(table table[ table...])`" 179 | msgstr "`NoHashJoin(テーブル テーブル[ テーブル...])`" 180 | 181 | #: ../../hint_list.md c2971905586543b487fb53812bf35961 182 | msgid "Forces to *not* do hash join for the joins on the tables specified." 183 | msgstr "指定されたテーブルで構成する結合にハッシュ結合が行われないように強制します。" 184 | 185 | #: ../../hint_list.md ae780b74c8524858bfd7b88696af6e97 186 | msgid "`NoMergeJoin(table table[ table...])`" 187 | msgstr "`NoMergeJoin(テーブル テーブル[ テーブル...])`" 188 | 189 | #: ../../hint_list.md d24008e3567944be8aacae813ba4105e 190 | msgid "Forces to *not* do merge join for the joins on the tables specified." 191 | msgstr "指定されたテーブルで構成する結合にマージ結合が行われないように強制します。" 192 | 193 | #: ../../hint_list.md 8154344c9f9e47508fd63f089fffa3c2 194 | msgid "Join order" 195 | msgstr "結合順序" 196 | 197 | #: ../../hint_list.md c45be6a3fcc64f6e97c7386e9306a97b 198 | msgid "`Leading(table table[ table...])`" 199 | msgstr "`Leading(テーブル テーブル[ テーブル...])`" 200 | 201 | #: ../../hint_list.md 78b43f0317d9456789c4c5adf4ccddaf 202 | msgid "Forces join order as specified." 203 | msgstr "指定された結合順序に強制します。" 204 | 205 | #: ../../hint_list.md e882b1ca7bce4e0b814cf095200d9eb2 206 | msgid "`Leading()`" 207 | msgstr "`Leading(<結合のペア>)`" 208 | 209 | #: ../../hint_list.md c18c0f1dca87413e8e319600619b7867 210 | msgid "Forces join order and directions as specified. A join pair is a pair of tables and/or other join pairs enclosed by parentheses, which can make a nested structure." 211 | msgstr "指定された結合順序と方向を強制します。結合ペアは、括弧で囲まれたテーブルや他の結合ペアのペアであり、入れ子構造を作ることができます。" 212 | 213 | #: ../../hint_list.md 3711c2f8a3c04944bf5762e3ae68cdd1 214 | msgid "Behavior control on Join" 215 | msgstr "結合時の挙動制御" 216 | 217 | #: ../../hint_list.md b99d34945e5a4d07a030a34ed76e47a2 218 | msgid "`Memoize(table table[ table...])`" 219 | msgstr "`Memoize(テーブル テーブル[ テーブル...])`" 220 | 221 | #: ../../hint_list.md 9866d5d20fb94c0099520bcb6edddbd1 222 | msgid "Allows the topmost join of a join among the specified tables to Memoize the inner result. Not enforced." 223 | msgstr "指定されたテーブル間の結合の最上位の結合において内部表の結果をメモすることを許可する (これは強制ではないことに注意)。" 224 | 225 | #: ../../hint_list.md 8f6a69e9f51a49f1ae925809bb47a14d 226 | msgid "`NoMemoize(table table[ table...])`" 227 | msgstr "`NoMemoize(テーブル テーブル[ テーブル...])`" 228 | 229 | #: ../../hint_list.md a73672326e2046e59e895b5e0baedef1 230 | msgid "Inhibits the topmost join of a join among the specified tables from Memoizing the inner result." 231 | msgstr "指定されたテーブル間の結合の最上位の結合において内部表の結果をメモすることを禁止します。" 232 | 233 | #: ../../hint_list.md 3872222d3ec048a98dbb3deb96f950aa 234 | msgid "Row number correction" 235 | msgstr "見積り行数の補正" 236 | 237 | #: ../../hint_list.md 180b1e30ad6e4342b88089cf66a14c29 238 | msgid "`Rows(table table[ table...] correction)`" 239 | msgstr "`Rows(テーブル テーブル[ テーブル...] 行数補正)`" 240 | 241 | #: ../../hint_list.md 827854e5182f4f859f79abaeda7ad8a0 242 | msgid "" 243 | "Corrects row number of a result of the joins on the tables specified. The available correction methods are absolute (#), addition (+), subtract (-) and multiplication (*). " 244 | " should be a string that strtod() can understand." 245 | msgstr "指定されたテーブルの結合結果の見積り行数を補正します。補正方法は、絶対値(#)、加算(+)、減算(-)、乗算(*)です。はstrtod()が読み込める文字列でなければなりません。" 246 | 247 | #: ../../hint_list.md a47c2a56dcea4861ba83cfdd8bcbea11 248 | msgid "Parallel query configuration" 249 | msgstr "パラレルクエリの設定" 250 | 251 | #: ../../hint_list.md ad67231a118a4c0d8114f74dc9d67afc 252 | msgid "`Parallel(table <# of workers> [soft|hard])`" 253 | msgstr "`Parallel(table <ワーカー数> [soft|hard])`" 254 | 255 | #: ../../hint_list.md 9aaf73225b934735bbbee9f49469340e 256 | msgid "" 257 | "Enforces or inhibits parallel execution of the specified table. <# of workers> is the desired number of parallel workers, where zero means inhibiting parallel execution. If the third " 258 | "parameter is soft (default), it just changes max\\_parallel\\_workers\\_per\\_gather and leaves everything else to the planner. Hard enforces the specified number of workers." 259 | msgstr "" 260 | "指定されたテーブルの並列実行を強制または禁止します。<ワーカー数>は希望する並列ワーカー数で、0は並列実行を禁止することを意味します。第3パラメータがsoft(デフォルト)の場合、" 261 | "max_parallel_workers_per_gatherを変更するだけで、その他すべてはプランナに任せます。hardは指定された数のワーカーを強制することを意味します。" 262 | 263 | #: ../../hint_list.md d22ccbc78ad648498c306050c5b494f2 264 | msgid "GUC" 265 | msgstr "GUCパラメータ" 266 | 267 | #: ../../hint_list.md 31157060ff3e4e74b9e1617bb5351fe5 268 | msgid "`Set(GUC-param value)`" 269 | msgstr "`Set(GUCパラメータ 値)`" 270 | 271 | #: ../../hint_list.md 44a5a20bd91841e19c3a21d01286b5b4 272 | msgid "Sets GUC parameter to the value defined while planner is running." 273 | msgstr "プランナが実行中の間、GUCパラメータの値を設定します。" 274 | 275 | #~ msgid "copyright (c) 2012-2024, nippon telegraph and telephone corporation" 276 | #~ msgstr "copyright (c) 2012-2024, nippon telegraph and telephone corporation" 277 | 278 | #~ msgid "Forces not to do index only scan on the table. Available for PostgreSQL 9.2 and later." 279 | #~ msgstr "指定されたテーブルにインデックスオンリースキャンを行わないように強制します。PostgreSQL 9.2以降で利用可能です。" 280 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/hint_table.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan hint table. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-10 08:24+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../hint_table.md:1 f67cbaf723be46bb8f7a0f7fd7a8079e 25 | msgid "The hint table" 26 | msgstr "ヒントテーブル" 27 | 28 | #: ../../hint_table.md:3 32621de851304428a1f227c2692a72c7 29 | msgid "" 30 | "Hints can be specified in a comment, still this can be inconvenient in the case where queries cannot be edited. In the case, hints can be placed in a special " 31 | "table named `\"hint_plan.hints\"`. The table consists of the following columns:" 32 | msgstr "" 33 | "ヒントは特別な形式のコメント内に記載されていますがクエリを編集できない場合には不便です。このような場合には `\"hint_plan.hints\"` という名前の特別なテーブルにヒ" 34 | "ントを置くことができます。このテーブルは以下のカラムで構成されています。" 35 | 36 | #: ../../hint_table.md ca09095a2eb747beacb5c3b9ca2d4228 37 | msgid "column" 38 | msgstr "列名" 39 | 40 | #: ../../hint_table.md 49581c288ab34cca94190af63ca3eeb0 41 | msgid "description" 42 | msgstr "説明" 43 | 44 | #: ../../hint_table.md 22b179cbf8a1406e81c47a7671b3ba65 45 | msgid "`id`" 46 | msgstr "`id`" 47 | 48 | #: ../../hint_table.md 03519b5619134fedb8f2b610baeb50ee 49 | msgid "Unique number to identify a row for a hint.
This column is filled automatically by sequence." 50 | msgstr "ユーザがヒントの行を識別するためのユニークな番号です。
この列はシーケンスによって自動的に埋められます。" 51 | 52 | #: ../../hint_table.md 3d7e591abdf04eed953b0027296e0104 53 | msgid "`norm_query_string`" 54 | msgstr "`norm_query_string`" 55 | 56 | #: ../../hint_table.md d16b18fd0f634ebfbe7c58271923d74d 57 | msgid "A pattern matching with the query to be hinted.
Constants in the query are replaced by '?' as in the following example." 58 | msgstr "実行計画を制御したいクエリを指定します。
クエリ内の定数は下記の例のように'?'に置き換えます。" 59 | 60 | #: ../../hint_table.md 333285c08e7846ad961b99b14bfcd979 61 | msgid "`application_name`" 62 | msgstr "`application_name`" 63 | 64 | #: ../../hint_table.md 760fd24060c0437d8b474ac5d3a6f786 65 | msgid "" 66 | "The value of `application_name` where sessions can apply a hint.
The hint in the example below applies to sessions connected from psql.
An empty " 67 | "string implies that all sessions will apply the hint." 68 | msgstr "" 69 | "ヒントの適用対象のアプリケーション名を指定します。
下記の例ではpsqlから実行されたクエリのみがヒントの適用対象となります。
全てのアプリケーションにヒント" 70 | "を適用したいときは、空文字列を登録します。" 71 | 72 | #: ../../hint_table.md c171ad26a5bb4ae78100ecc091bc6e13 73 | msgid "`hints`" 74 | msgstr "`hints`" 75 | 76 | #: ../../hint_table.md 96055c136dbf4d1aa3b851b205088b40 77 | msgid "Hint phrase.
This must be a series of hints excluding surrounding comment marks." 78 | msgstr "ヒント句を指定します。
コメントの記号を除いたヒントのみを登録します。" 79 | 80 | #: ../../hint_table.md:14 923fb84f5fe348dcabe5b8aad4a334b8 81 | msgid "The following example shows how to operate with the hint table." 82 | msgstr "以下の例はヒントテーブルの操作方法を示しています。" 83 | 84 | #: ../../hint_table.md:31 dc2810bd37aa46ec9dbacf93447b8b79 85 | msgid "" 86 | "The hint table is owned by the extension owner and has the same default privileges as of the time of its creation, during `CREATE EXTENSION`. Hints in the " 87 | "hint table are prioritized over hints in comments." 88 | msgstr "" 89 | "ヒントテーブルは拡張機能の所有者が所有し、拡張機能作成時におけるデフォルトの権限を持ちます。ヒントテーブル内のヒントはコメント内のヒントよりも優先されます。" 90 | 91 | #: ../../hint_table.md:35 db26de13734041f7ad7b024e92b581ed 92 | msgid "Types of hints" 93 | msgstr "ヒントの種類" 94 | 95 | #: ../../hint_table.md:37 fd001d1b4af9467cbb2c4306455e4b8a 96 | msgid "" 97 | "Hinting phrases are classified in multiple types based on what kind of object and how they can affect the planner. See [Hint list](#hint-list) for more " 98 | "details." 99 | msgstr "" 100 | 101 | #: ../../hint_table.md:41 fcf889fb655f490e91639fe51d6c64a2 102 | msgid "Hints for Scan methods" 103 | msgstr "スキャン方法" 104 | 105 | #: ../../hint_table.md:43 7fcc906d0b5c4700b165a9f5c955fe14 106 | msgid "" 107 | "Scan method hints enforce specific scanning methods on the target table. `pg_hint_plan` recognizes the target table by alias names if any. These are for " 108 | "example `SeqScan` or `IndexScan`." 109 | msgstr "" 110 | "スキャン方法のヒントは、対象のテーブルに対して特定のスキャン方法を強制するものです。`pg_hint_plan`は対象のテーブルに別名が存在する場合、別名で認識します。この" 111 | "種類の例は`SeqScan`や`IndexScan`などです。" 112 | 113 | #: ../../hint_table.md:47 3ae34bdea12d4a8e8ea2c7ec5446eebe 114 | msgid "" 115 | "Scan hints work on ordinary tables, inheritance tables, UNLOGGED tables, temporary tables and system catalogs. External (foreign) tables, table functions, " 116 | "VALUES clause, CTEs, views and subqueries are not affected." 117 | msgstr "" 118 | "スキャン方法のヒントは、通常のテーブル・継承テーブル・UNLOGGEDテーブル・一時テーブル・システムカタログに効果があります。外部テーブル・テーブル関数・VALUES句・" 119 | "CTE・ビュー・副問い合わせには影響を与えません。" 120 | 121 | #: ../../hint_table.md:59 3088543edf274b16999ab0fdb8f6b7d7 122 | msgid "Hints for Join methods" 123 | msgstr "結合方法" 124 | 125 | #: ../../hint_table.md:61 ea1c9b0735be427787403b05e87fb302 126 | msgid "Join method hints enforce the join methods of the joins involving the specified tables." 127 | msgstr "結合方法のヒントは、指定したテーブルを含む結合の結合方法を強制するものです。" 128 | 129 | #: ../../hint_table.md:64 4929b52aab0a436782c74c93d2d759de 130 | msgid "" 131 | "This can affect joins only on ordinary tables. Inheritance tables, UNLOGGED tables, temporary tables, external (foreign) tables, system catalogs, table " 132 | "functions, VALUES command results and CTEs are allowed to be in the parameter list. Joins on views and subqueries are not affected." 133 | msgstr "" 134 | "これは、通常のテーブル・継承テーブル・UNLOGGEDテーブル・一時テーブル・外部テーブル・システムカタログ・テーブル関数・VALUESコマンド結果、およびパラメータリスト" 135 | "に含めることが許可されているCTEの結合にのみ影響を与えます。しかし、ビュー・副問い合わせの結合には影響を与えません。" 136 | 137 | #: ../../hint_table.md:69 885c9cba398e450da95b1a83679dcf35 138 | msgid "Hints for Joining order" 139 | msgstr "結合順" 140 | 141 | #: ../../hint_table.md:71 705f15a4b07e4fd38ebb4bbffffeb730 142 | msgid "" 143 | "This hint, named \"Leading\", enforces the order of join on two or more tables. There are two methods of enforcing it. The first method enforces a specific " 144 | "order of joining but does not restrict the direction at each join level. The second method enforces the join direction additionally. See [hint list](#hint-" 145 | "list) for more details. For example:" 146 | msgstr "" 147 | "`Leading`ヒントは、2つ以上のテーブルの結合順を強制するものです。強制には2つの方法があります。1つは特定の結合順を強制し各結合レベルでは方向を制限しない方法で" 148 | "す。もう1つは結合の方向を追加で指定するものです。詳細は[ヒント一覧](#hint-list)で確認してください。以下は例です。" 149 | 150 | #: ../../hint_table.md:88 45d67ea2eed144fe90f94d5f333bd463 151 | msgid "Hints for Row number corrections" 152 | msgstr "行数補正" 153 | 154 | #: ../../hint_table.md:90 eefdbaa1b6694fe7befcc442e4277d12 155 | msgid "This hint, named \"Rows\", changes the row number estimation of joins that comes from restrictions in the planner. For example:" 156 | msgstr "`Rows`ヒントは、プランナの制限に起因する結合の見積り行数誤りを修正します。以下は例です。" 157 | 158 | #: ../../hint_table.md:100 65fdbb9e0e504d81b3e76b81653ee213 159 | msgid "Hints for parallel plans" 160 | msgstr "パラレルプラン" 161 | 162 | #: ../../hint_table.md:102 76ac76f5f3df418aa80fba2605557453 163 | msgid "" 164 | "This hint, named `Parallel`, enforces parallel execution configuration on scans. The third parameter specifies the strength of the enforcement. `soft` means " 165 | "that `pg_hint_plan` only changes `max_parallel_worker_per_gather` and leaves all the others to the planner to set. `hard` changes other planner parameters so " 166 | "as to forcibly apply the update. This can affect ordinary tables, inheritance parents, unlogged tables and system catalogs. External tables, table functions, " 167 | "`VALUES` clauses, CTEs, views and subqueries are not affected. Internal tables of a view can be specified by its real name or its alias as the target " 168 | "object. The following example shows that the query is enforced differently on each table:" 169 | msgstr "" 170 | "`Parallel`ヒント は、スキャンの並列実行の設定を強制するものです。第3パラメータは強制の強さを指定します。`soft` は `pg_hint_plan` が " 171 | "`max_parallel_worker_per_gather` を変更するだけで、その他のすべてはプランナに任せることを意味します。`hard`はプランナのパラメータを変更し、強制的にその数値を適" 172 | "用するようにします。\n" 173 | "このヒントは通常のテーブル・継承の親テーブル・UNLOGGEDテーブル・システムカタログに影響を与えることができます。外部テーブル・テーブル関数・VALUE句・CTE・" 174 | "ビュー・サブクエリには影響を与えません。\n" 175 | "ビューの内部テーブルについては、対象オブジェクトとして実名/別名を用いて指定できます。次の例のクエリは、各テーブルで異なる設定を強制しています。" 176 | 177 | #: ../../hint_table.md:138 02fb713ed8864bc58e4c6af77fb9cc21 178 | msgid "GUC parameters set during planning" 179 | msgstr "プランニング中のGUCパラメータの設定" 180 | 181 | #: ../../hint_table.md:140 c8915576c86a451bb8c22caffb0739e5 182 | msgid "" 183 | "`Set` hints change GUC parameters just while planning. GUC parameter shown in [Query Planning](http://www.postgresql.org/docs/current/static/runtime-config-" 184 | "query.html) can have the expected effects on planning unless an other hint conflicts with the planner method configuration parameters. When multiple hints " 185 | "change the same GUC, the last hint takes effect. [GUC parameters for `pg_hint_plan`](#guc-parameters-for-pg_hint_plan) are also settable by this hint but it " 186 | "may not work as expected. See [Functional limitations](#functional-limitations) for details." 187 | msgstr "" 188 | "`Set`ヒントはプランニング中のみGUCパラメータを変更します。 [Query Planning](http://www.postgresql.org/docs/current/static/runtime-config-query.html) で示した" 189 | "GUCパラメータは、他のヒントがプランナの設定パラメータと競合しない限り、期待される効果を発揮することができます。同じGUCパラメータに関するヒントのうち、最後のも" 190 | "のが効果を発揮します。[pg_hint_planのGUCパラメータ](#guc-parameters-for-pg_hint_plan) もこのヒントで設定可能ですが期待通りには動作しません。詳しくは[機能的な制" 191 | "限事項](functional_limitations)を参照してください。" 192 | 193 | #: ../../hint_table.md:156 da73baff64f04c07ab673ecae83330bc 194 | msgid "GUC parameters for `pg_hint_plan`" 195 | msgstr "pg_hint_planのGUCパラメータ" 196 | 197 | #: ../../hint_table.md:158 74677aeddbf34e859a8ec765fef33c7d 198 | msgid "The following GUC parameters affect the behavior of `pg_hint_plan`:" 199 | msgstr "以下のGUCパラメータは`pg_hint_plan`の動作を制御します。" 200 | 201 | #: ../../hint_table.md 56e1e159fad54f27958655225400031f 202 | msgid "Parameter name" 203 | msgstr "パラメータ名" 204 | 205 | #: ../../hint_table.md 1eb1991b81d94c6289004fad098cdced 206 | msgid "Description" 207 | msgstr "説明" 208 | 209 | #: ../../hint_table.md 6a9158ac4c504563998ea54063cbe622 210 | msgid "Default" 211 | msgstr "デフォルト値" 212 | 213 | #: ../../hint_table.md 32fef9a8c49f4dfd89602fe7dab1b09d 214 | msgid "`pg_hint_plan.enable_hint`" 215 | msgstr "`pg_hint_plan.enable_hint`" 216 | 217 | #: ../../hint_table.md 6221aa8a27f24ce2a5e90358cbccc16f 218 | msgid "True enables `pg_hint_plan`." 219 | msgstr "Trueはpg_hint_planを有効にします。" 220 | 221 | #: ../../hint_table.md f3b980fcf00d47168d2aa5a2162391e1 222 | msgid "`on`" 223 | msgstr "`on`" 224 | 225 | #: ../../hint_table.md 310d50f8e0724d70a4295a2342f87094 226 | msgid "`pg_hint_plan.enable_hint_table`" 227 | msgstr "`pg_hint_plan.enable_hint_table`" 228 | 229 | #: ../../hint_table.md 25dbdbcdaab544ee86a967920b690836 230 | msgid "True enables hinting by table." 231 | msgstr "Trueはテーブルによってヒントを指定する機能を有効にします。" 232 | 233 | #: ../../hint_table.md 679148d306b34e2d9956c21361b760c2 b97fab529ba6473f81a05d48725bba64 234 | msgid "`off`" 235 | msgstr "`off`" 236 | 237 | #: ../../hint_table.md d9b4dfe654c24b49861ceb5a994575ba 238 | msgid "`pg_hint_plan.parse_messages`" 239 | msgstr "`pg_hint_plan.parse_messages`" 240 | 241 | #: ../../hint_table.md 294d65b227f04073b023232548232b4a 242 | msgid "Specifies the log level of hint parse error. Valid values are `error`, `warning`, `notice`, `info`, `log`, `debug`." 243 | msgstr "指定したヒントを構文解析できなかった場合のログメッセージのレベルを指定します。指定可能な値は、`error`、`warning`、`notice`、`info`、`log`、`debug`です。" 244 | 245 | #: ../../hint_table.md 5e4d1e6b44a1413983e4191c2dc55900 64383f13cb2d49c89a2d730c9bad4f83 246 | msgid "`INFO`" 247 | msgstr "`INFO`" 248 | 249 | #: ../../hint_table.md afdb6a0bf4b44ee98fdbf547bc8aa20f 250 | msgid "`pg_hint_plan.debug_print`" 251 | msgstr "`pg_hint_plan.debug_print`" 252 | 253 | #: ../../hint_table.md 967c06b80b7e44908bdeb41cdea10df6 254 | msgid "Controls debug print and verbosity. Valid values are `off`, `on`, `detailed` and `verbose`." 255 | msgstr "動作状況を示すログメッセージの出力を制御します。指定可能な値は `off`、`on`、`detailed`、`verbose`です。" 256 | 257 | #: ../../hint_table.md e950028fedfd47478a88207c4d684714 258 | msgid "`pg_hint_plan.message_level`" 259 | msgstr "`pg_hint_plan.message_level`" 260 | 261 | #: ../../hint_table.md 9589d482e9ed4f4c98b3c302e34fbce9 262 | msgid "Specifies message level of debug print. Valid values are `error`, `warning`, `notice`, `info`, `log`, `debug`." 263 | msgstr "動作ログメッセージのログレベルを指定します。指定可能な値は、`error`、`warning`、`notice`、`info`、`log`、`debug`です。" 264 | 265 | #~ msgid "" 266 | #~ "Hinting phrases are classified into six types based on what kind of object and how they can affect planning. Scanning methods, join methods, joining order, " 267 | #~ "row number correction, parallel query, and GUC setting. You will see the lists of hint phrases of each type in [Hint list](#hint-list)." 268 | #~ msgstr "" 269 | #~ "ヒント句はどの対象にどのような影響をプランニングに与えるかに基づいて6種類に分類されます。種類はスキャン方法・結合方法・結合順序・見積り行数補正・並列実行の" 270 | #~ "設定・GUCパラメータです。具体的なヒント句は、[ヒント一覧](#hint_list)を参照してください。" 271 | 272 | #~ msgid "GUC parameters temporarily setting" 273 | #~ msgstr "GUCパラメータ" 274 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/index.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan index page. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # 7 | #, fuzzy 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan \n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-03-02 12:25+0800\n" 13 | "PO-Revision-Date: 2023-03-02 12:28+0800\n" 14 | "Last-Translator: Julien Rouhaud \n" 15 | "Language: ja\n" 16 | "Language-Team: \n" 17 | "Plural-Forms: nplurals=1; plural=0;\n" 18 | "MIME-Version: 1.0\n" 19 | "Content-Type: text/plain; charset=utf-8\n" 20 | "Content-Transfer-Encoding: 8bit\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | 23 | #: ../../index.md:1 1477c3a63d6140379ebc8ee8e6949aac 24 | msgid "pg_hint_plan 1.8" 25 | msgstr "pg_hint_plan 1.8" 26 | 27 | #: ../../index.md:2 b5608f9be7e34270a28850acab4a3fae 28 | msgid "Table of Contents" 29 | msgstr "目次" 30 | 31 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/installation.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan installation. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-10 08:29+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../installation.md:1 fadb13f484a44269a9b76df61f8dc618 25 | msgid "Installation" 26 | msgstr "インストール" 27 | 28 | #: ../../installation.md:3 aa2c540a272a419e875bd684665aad1c 29 | msgid "This section describes the installation steps." 30 | msgstr "このセクションはpg_hint_planのインストール方法について説明します。" 31 | 32 | #: ../../installation.md:5 fba567f87a4d49eab2495a3fc80c791b 33 | msgid "building binary module" 34 | msgstr "ビルド" 35 | 36 | #: ../../installation.md:7 c0d348a44efd4fb7a24080a8c3ba5473 37 | msgid "" 38 | "Simply run `make` at the top of the source tree, then `make install` as " 39 | "an appropriate user. The `PATH` environment variable should be set " 40 | "properly to point to a PostgreSQL set of binaries:" 41 | msgstr "" 42 | "ソースツリーの先頭で `make` を実行し、適切なユーザで `make install` を実" 43 | "行してください。環境変数 `PATH` は、PostgreSQLのバイナリを指すように適切" 44 | "に設定する必要があります。" 45 | 46 | #: ../../installation.md:17 e97c510e8ca24eb5919c2a5fef6d1f47 47 | msgid "Loading `pg_hint_plan`" 48 | msgstr "`pg_hint_plan`のロード" 49 | 50 | #: ../../installation.md:19 1c8ec801902f429d8e695cf03dc089c1 51 | msgid "" 52 | "`pg_hint_plan` does not require `CREATE EXTENSION`. Loading it with a " 53 | "`LOAD` command will activate it and of course you can load it globally " 54 | "by setting `shared_preload_libraries` in `postgresql.conf`. Or you " 55 | "might be interested in `ALTER USER SET`/`ALTER DATABASE SET` for " 56 | "automatic loading in specific sessions." 57 | msgstr "" 58 | "`pg_hint_plan` は基本的に`CREATE EXTENSION`を必要としません。単純に`LOAD`" 59 | "コマンドで有効化できます。もちろん、`postgresql.conf`の" 60 | "`shared_preload_libraries` を設定することで全体にロード することもできま" 61 | "す。また、特定のユーザに対し自動的にロードするための`ALTER USER SET`/" 62 | "`ALTER DATABASE SET`に興味があるかもしれません。" 63 | 64 | #: ../../installation.md:30 9cad4df70ec04fa594d93a476c9f8f02 65 | msgid "" 66 | "Run `CREATE EXTENSION` and `SET pg_hint_plan.enable_hint_table TO on` " 67 | "if you are planning to use the hint table." 68 | msgstr "" 69 | "ヒントテーブルを使用する場合は、`CREATE EXTENSION` を実行し`SET " 70 | "pg_hint_plan.enable_hint_table TO on`を実行してください。" 71 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/requirements.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan requirements. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-10 08:31+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../requirements.md:1 26f3405d14e1471d98d797d27f70f0e1 25 | msgid "Requirements" 26 | msgstr "動作環境" 27 | 28 | #: ../../requirements.md:3 e2a338fd547c4102a8ba452a1ce76fe4 29 | msgid "pg_hint_plan 1.8 requires PostgreSQL 18." 30 | msgstr "pg_hint_plan 1.8 は PostgreSQL 18 のみをサポートします。" 31 | 32 | #: ../../requirements.md:5 2f43757380444e08ab0e181a788a1b78 33 | msgid "PostgreSQL versions tested" 34 | msgstr "テスト済みのPostgreSQLバージョン" 35 | 36 | #: ../../requirements.md:7 744d9ef1bc3240a9af15e103cf476a19 37 | msgid "Version 18" 38 | msgstr "・バージョン 18" 39 | 40 | #: ../../requirements.md:9 27a4d38176f445efaec1e1f5367ab674 41 | msgid "OS versions tested" 42 | msgstr "テスト済みのOSバージョン" 43 | 44 | #: ../../requirements.md:11 eb5a718ba289445eb2478b2650b23bfd 45 | msgid "CentOS 8.5" 46 | msgstr "・CentOS 8.5" 47 | 48 | #: ../../requirements.md:13 4f3befbd04964972b9a7fb70ba217dfe 49 | msgid "See also" 50 | msgstr "関連項目" 51 | 52 | #: ../../requirements.md:16 13bf779462964c18a3e97148198d04f3 53 | msgid "References" 54 | msgstr "" 55 | 56 | #: ../../requirements.md:18 554dc9beb49d4774a7e3c99e426cc9c1 57 | msgid "[EXPLAIN](http://www.postgresql.org/docs/current/static/sql-explain.html)" 58 | msgstr "[EXPLAIN](http://www.postgresql.org/docs/current/static/sql-explain.html)" 59 | 60 | #: ../../requirements.md:19 f960539e7df047a39a37f7660b8ed5e5 61 | msgid "[SET](http://www.postgresql.org/docs/current/static/sql-set.html)" 62 | msgstr "[SET](http://www.postgresql.org/docs/current/static/sql-set.html)" 63 | 64 | #: ../../requirements.md:20 bab201f98ce04f06a704b1f766459215 65 | msgid "" 66 | "[Server Config](http://www.postgresql.org/docs/current/static/runtime-config." 67 | "html)" 68 | msgstr "" 69 | "[Server Config](http://www.postgresql.org/docs/current/static/runtime-config." 70 | "html)" 71 | 72 | #: ../../requirements.md:21 562b990d519e4102a2fe16ae980a37ef 73 | msgid "" 74 | "[Parallel Plans](http://www.postgresql.org/docs/current/static/parallel-plans." 75 | "html)" 76 | msgstr "" 77 | "[Parallel Plans](http://www.postgresql.org/docs/current/static/parallel-plans." 78 | "html)" 79 | 80 | #~ msgid "PostgreSQL documents" 81 | #~ msgstr "PostgreSQLドキュメント" 82 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/synopsis.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan synopsis. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-10 08:42+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../synopsis.md:1 5f2c3282c7b24c629ef71f0dbfff3d60 25 | msgid "Synopsis" 26 | msgstr "概要" 27 | 28 | #: ../../synopsis.md:3 a16cf76f5d7f484da866552664d1ec30 29 | msgid "`pg_hint_plan` makes it possible to tweak PostgreSQL execution plans using \"hints\" in SQL comments, as of `/*+ SeqScan(a) */`." 30 | msgstr "`pg_hint_plan`はSQLコメント内のヒント (`/*+ SeqScan(a) */`など) を用いることで実行計画を制御することができます。" 31 | 32 | #: ../../synopsis.md:6 e5e5c5196620409aa703e094e4d8ad9f 33 | msgid "" 34 | "PostgreSQL uses a cost-based optimizer, which utilizes data statistics, not static rules. The planner (optimizer) estimates costs of each possible execution plans for a SQL statement then the execution plan " 35 | "with the lowest cost is executed. The planner does its best to select the best execution plan, but is not always perfect, since it doesn't take into account some of the data properties or correlations between " 36 | "columns." 37 | msgstr "" 38 | "PostgreSQLのプランナは静的なルールではなくデータの統計情報を用いたコストベースのオプティマイザを利用しています。プランナ(オプティマイザ)はSQL文に対して可能な限りの実行計画のコストを推定し、最もコストが低い実行" 39 | "計画を選択します。プランナは最適な実行計画を選択するために最善を尽くしますが、データの特性やカラム間の相関を考慮していないため、必ずしも完璧ではありません。" 40 | -------------------------------------------------------------------------------- /docs/locale/ja/LC_MESSAGES/uninstallation.po: -------------------------------------------------------------------------------- 1 | # LANGUAGE message translation file for pg_hint_plan uninstallation. 2 | # Copyright (C) 2012-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 3 | # This file is distributed under the same license as the pg_hint_plan 4 | # package. 5 | # Julien Rouhaud , 2023. 6 | # Tatsuro Yamada , 2023. 7 | # 8 | msgid "" 9 | msgstr "" 10 | "Project-Id-Version: pg_hint_plan\n" 11 | "Report-Msgid-Bugs-To: \n" 12 | "POT-Creation-Date: 2023-11-09 10:50+0900\n" 13 | "PO-Revision-Date: 2023-11-10 08:46+0900\n" 14 | "Last-Translator: Tatsuro Yamada \n" 15 | "Language-Team: \n" 16 | "Language: ja\n" 17 | "MIME-Version: 1.0\n" 18 | "Content-Type: text/plain; charset=utf-8\n" 19 | "Content-Transfer-Encoding: 8bit\n" 20 | "Plural-Forms: nplurals=1; plural=0;\n" 21 | "Generated-By: Babel 2.12.1\n" 22 | "X-Generator: Poedit 3.2.2\n" 23 | 24 | #: ../../uninstallation.md:1 f3cc8a1c1ca3459ab9d7e0d78b5ebad0 25 | msgid "Uninstallation" 26 | msgstr "アンインストール" 27 | 28 | #: ../../uninstallation.md:3 aa4ccdaf9927460fb3c337548536e4f3 29 | msgid "" 30 | "`make uninstall` in the top directory of source tree will uninstall the " 31 | "installed files if you installed from the source tree and it is left " 32 | "available. Setting the environment variable `PATH` may be necessary." 33 | msgstr "" 34 | "ソース ツリーからインストールし、それが利用可能なままになっている場合は、" 35 | "ソース ツリーの最上位ディレクトリにある `make uninstall` を実行するとイン" 36 | "ストールされたファイルがアンインストールされます。環境変数 `PATH` の設定" 37 | "が必要な場合があります。" 38 | -------------------------------------------------------------------------------- /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/requirements.in: -------------------------------------------------------------------------------- 1 | # RTD only supports sphinx up to 5.3.0 2 | sphinx==5.3.0 3 | 4 | # those are sphinx dependencies, but unfortunately RTD doesn't support the 5 | # latest versions, so we need to explicitly pin them 6 | sphinxcontrib-applehelp==1.0.2 7 | sphinxcontrib-htmlhelp==2.0.0 8 | 9 | sphinx_rtd_theme 10 | myst_parser 11 | sphinx-intl 12 | -------------------------------------------------------------------------------- /docs/requirements.md: -------------------------------------------------------------------------------- 1 | # Requirements 2 | 3 | pg_hint_plan 1.8 requires PostgreSQL 18. 4 | 5 | PostgreSQL versions tested 6 | 7 | - Version 18 8 | 9 | OS versions tested 10 | 11 | - CentOS 8.5 12 | 13 | See also 14 | -------- 15 | 16 | ## References 17 | 18 | - [EXPLAIN](http://www.postgresql.org/docs/current/static/sql-explain.html) 19 | - [SET](http://www.postgresql.org/docs/current/static/sql-set.html) 20 | - [Server Config](http://www.postgresql.org/docs/current/static/runtime-config.html) 21 | - [Parallel Plans](http://www.postgresql.org/docs/current/static/parallel-plans.html) 22 | -------------------------------------------------------------------------------- /docs/requirements.txt: -------------------------------------------------------------------------------- 1 | # 2 | # This file is autogenerated by pip-compile with Python 3.9 3 | # by the following command: 4 | # 5 | # pip-compile --resolver=backtracking requirements.in 6 | # 7 | alabaster==0.7.13 8 | # via sphinx 9 | babel==2.12.1 10 | # via 11 | # sphinx 12 | # sphinx-intl 13 | certifi==2025.1.31 14 | # via requests 15 | charset-normalizer==3.0.1 16 | # via requests 17 | click==8.1.3 18 | # via sphinx-intl 19 | docutils==0.19 20 | # via 21 | # myst-parser 22 | # sphinx 23 | idna==3.7 24 | # via requests 25 | imagesize==1.4.1 26 | # via sphinx 27 | importlib-metadata==7.1.0 28 | # via sphinx 29 | jinja2==3.1.6 30 | # via 31 | # myst-parser 32 | # sphinx 33 | markdown-it-py==2.2.0 34 | # via 35 | # mdit-py-plugins 36 | # myst-parser 37 | markupsafe==2.1.2 38 | # via jinja2 39 | mdit-py-plugins==0.3.4 40 | # via myst-parser 41 | mdurl==0.1.2 42 | # via markdown-it-py 43 | myst-parser==0.19.0 44 | # via -r requirements.in 45 | packaging==23.0 46 | # via sphinx 47 | pygments==2.16.1 48 | # via sphinx 49 | pyyaml==6.0 50 | # via myst-parser 51 | requests==2.32.3 52 | # via sphinx 53 | snowballstemmer==2.2.0 54 | # via sphinx 55 | sphinx==5.3.0 56 | # via 57 | # -r requirements.in 58 | # myst-parser 59 | # sphinx-intl 60 | # sphinx-rtd-theme 61 | sphinx-intl==2.1.0 62 | # via -r requirements.in 63 | sphinx-rtd-theme==0.5.1 64 | # via -r requirements.in 65 | sphinxcontrib-applehelp==1.0.2 66 | # via 67 | # -r requirements.in 68 | # sphinx 69 | sphinxcontrib-devhelp==1.0.2 70 | # via sphinx 71 | sphinxcontrib-htmlhelp==2.0.0 72 | # via 73 | # -r requirements.in 74 | # sphinx 75 | sphinxcontrib-jsmath==1.0.1 76 | # via sphinx 77 | sphinxcontrib-qthelp==1.0.3 78 | # via sphinx 79 | sphinxcontrib-serializinghtml==1.1.5 80 | # via sphinx 81 | urllib3==2.3.0 82 | # via requests 83 | zipp==3.21.0 84 | # via importlib-metadata 85 | 86 | # The following packages are considered to be unsafe in a requirements file: 87 | # setuptools 88 | -------------------------------------------------------------------------------- /docs/synopsis.md: -------------------------------------------------------------------------------- 1 | # Synopsis 2 | 3 | `pg_hint_plan` makes it possible to tweak PostgreSQL execution plans using 4 | "hints" in SQL comments, as of `/*+ SeqScan(a) */`. 5 | 6 | PostgreSQL uses a cost-based optimizer, which utilizes data statistics, not 7 | static rules. The planner (optimizer) estimates costs of each possible 8 | execution plans for a SQL statement then the execution plan with the lowest 9 | cost is executed. The planner does its best to select the best execution 10 | plan, but is not always perfect, since it doesn't take into account some of 11 | the data properties or correlations between columns. 12 | -------------------------------------------------------------------------------- /docs/uninstallation.md: -------------------------------------------------------------------------------- 1 | # Uninstallation 2 | 3 | `make uninstall` in the top directory of source tree will uninstall the 4 | installed files if you installed from the source tree and it is left 5 | available. Setting the environment variable `PATH` may be necessary. 6 | 7 | $ cd pg_hint_plan-1.x.x 8 | $ su 9 | $ make uninstall 10 | -------------------------------------------------------------------------------- /expected/R_sample.out: -------------------------------------------------------------------------------- 1 | QUERY PLAN 2 | --------------------------------------------------------------------------- 3 | Merge Join (cost=xxx rows=100 width=29) 4 | Merge Cond: (t1.c1 = t2.c1) 5 | -> Index Scan using t1_i1 on t1 (cost=xxx rows=1000 width=15) 6 | -> Sort (cost=xxx rows=100 width=14) 7 | Sort Key: t2.c1 8 | -> Seq Scan on t2 (cost=xxx rows=100 width=14) 9 | (6 rows) 10 | 11 | -------------------------------------------------------------------------------- /expected/base_plan.out: -------------------------------------------------------------------------------- 1 | SET search_path TO public; 2 | -- query type 1 3 | EXPLAIN (COSTS false) SELECT * FROM t1, t2 WHERE t1.id = t2.id; 4 | QUERY PLAN 5 | -------------------------------------- 6 | Merge Join 7 | Merge Cond: (t1.id = t2.id) 8 | -> Index Scan using t1_pkey on t1 9 | -> Index Scan using t2_pkey on t2 10 | (4 rows) 11 | 12 | -- query type 2 13 | EXPLAIN (COSTS false) SELECT * FROM t1, t4 WHERE t1.val < 10; 14 | QUERY PLAN 15 | ----------------------------------------- 16 | Nested Loop 17 | -> Bitmap Heap Scan on t1 18 | Recheck Cond: (val < 10) 19 | -> Bitmap Index Scan on t1_val 20 | Index Cond: (val < 10) 21 | -> Materialize 22 | -> Seq Scan on t4 23 | (7 rows) 24 | 25 | -- query type 3 26 | EXPLAIN (COSTS false) SELECT * FROM t3, t4 WHERE t3.id = t4.id AND t4.ctid = '(1,1)'; 27 | QUERY PLAN 28 | --------------------------------------------- 29 | Merge Join 30 | Merge Cond: (t3.id = t4.id) 31 | -> Index Scan using t3_pkey on t3 32 | -> Sort 33 | Sort Key: t4.id 34 | -> Seq Scan on t4 35 | Filter: (ctid = '(1,1)'::tid) 36 | (7 rows) 37 | 38 | -- query type 4 39 | EXPLAIN (COSTS false) SELECT * FROM t1, t2 WHERE t1.id = t2.id AND t1.ctid = '(1,1)'; 40 | QUERY PLAN 41 | ----------------------------------------- 42 | Nested Loop 43 | -> Tid Scan on t1 44 | TID Cond: (ctid = '(1,1)'::tid) 45 | -> Index Scan using t2_pkey on t2 46 | Index Cond: (id = t1.id) 47 | (5 rows) 48 | 49 | -- query type 5 50 | EXPLAIN (COSTS false) SELECT * FROM t1, t3 WHERE t1.val = t3.val; 51 | QUERY PLAN 52 | -------------------------------- 53 | Hash Join 54 | Hash Cond: (t1.val = t3.val) 55 | -> Seq Scan on t1 56 | -> Hash 57 | -> Seq Scan on t3 58 | (5 rows) 59 | 60 | -- query type 6 61 | EXPLAIN (COSTS false) SELECT * FROM t1, t2, t3, t4 WHERE t1.id = t2.id AND t1.id = t3.id AND t1.id = t4.id; 62 | QUERY PLAN 63 | -------------------------------------------------- 64 | Nested Loop 65 | -> Merge Join 66 | Merge Cond: (t1.id = t4.id) 67 | -> Merge Join 68 | Merge Cond: (t1.id = t2.id) 69 | -> Index Scan using t1_pkey on t1 70 | -> Index Scan using t2_pkey on t2 71 | -> Sort 72 | Sort Key: t4.id 73 | -> Seq Scan on t4 74 | -> Index Scan using t3_pkey on t3 75 | Index Cond: (id = t1.id) 76 | (12 rows) 77 | 78 | -------------------------------------------------------------------------------- /expected/hint_table.out: -------------------------------------------------------------------------------- 1 | -- Tests for the hint table 2 | LOAD 'pg_hint_plan'; 3 | -- Attempting to use the hint table without the extension created 4 | -- emits a WARNING. 5 | SET pg_hint_plan.enable_hint_table TO on; 6 | SELECT 1; 7 | WARNING: cannot use the hint table 8 | HINT: Run "CREATE EXTENSION pg_hint_plan" to create the hint table. 9 | ?column? 10 | ---------- 11 | 1 12 | (1 row) 13 | 14 | SET pg_hint_plan.enable_hint_table TO off; 15 | CREATE EXTENSION pg_hint_plan; 16 | SET pg_hint_plan.enable_hint_table TO on; 17 | SELECT 1; 18 | ?column? 19 | ---------- 20 | 1 21 | (1 row) 22 | 23 | SET pg_hint_plan.enable_hint_table TO off; 24 | DROP EXTENSION pg_hint_plan; 25 | -------------------------------------------------------------------------------- /expected/oldextversions.out: -------------------------------------------------------------------------------- 1 | -- 2 | -- tests for upgrade paths 3 | -- 4 | CREATE EXTENSION pg_hint_plan VERSION "1.3.0"; 5 | \dx+ pg_hint_plan 6 | Objects in extension "pg_hint_plan" 7 | Object description 8 | --------------------------------- 9 | sequence hint_plan.hints_id_seq 10 | table hint_plan.hints 11 | type hint_plan.hints 12 | type hint_plan.hints[] 13 | (4 rows) 14 | 15 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.1"; 16 | \dx+ pg_hint_plan 17 | Objects in extension "pg_hint_plan" 18 | Object description 19 | --------------------------------- 20 | sequence hint_plan.hints_id_seq 21 | table hint_plan.hints 22 | type hint_plan.hints 23 | type hint_plan.hints[] 24 | (4 rows) 25 | 26 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.2"; 27 | \dx+ pg_hint_plan 28 | Objects in extension "pg_hint_plan" 29 | Object description 30 | --------------------------------- 31 | sequence hint_plan.hints_id_seq 32 | table hint_plan.hints 33 | type hint_plan.hints 34 | type hint_plan.hints[] 35 | (4 rows) 36 | 37 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.3"; 38 | \dx+ pg_hint_plan 39 | Objects in extension "pg_hint_plan" 40 | Object description 41 | --------------------------------- 42 | sequence hint_plan.hints_id_seq 43 | table hint_plan.hints 44 | type hint_plan.hints 45 | type hint_plan.hints[] 46 | (4 rows) 47 | 48 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.4"; 49 | \dx+ pg_hint_plan 50 | Objects in extension "pg_hint_plan" 51 | Object description 52 | --------------------------------- 53 | sequence hint_plan.hints_id_seq 54 | table hint_plan.hints 55 | type hint_plan.hints 56 | type hint_plan.hints[] 57 | (4 rows) 58 | 59 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.5"; 60 | \dx+ pg_hint_plan 61 | Objects in extension "pg_hint_plan" 62 | Object description 63 | --------------------------------- 64 | sequence hint_plan.hints_id_seq 65 | table hint_plan.hints 66 | type hint_plan.hints 67 | type hint_plan.hints[] 68 | (4 rows) 69 | 70 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.6"; 71 | \dx+ pg_hint_plan 72 | Objects in extension "pg_hint_plan" 73 | Object description 74 | --------------------------------- 75 | sequence hint_plan.hints_id_seq 76 | table hint_plan.hints 77 | type hint_plan.hints 78 | type hint_plan.hints[] 79 | (4 rows) 80 | 81 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.7"; 82 | \dx+ pg_hint_plan 83 | Objects in extension "pg_hint_plan" 84 | Object description 85 | --------------------------------- 86 | sequence hint_plan.hints_id_seq 87 | table hint_plan.hints 88 | type hint_plan.hints 89 | type hint_plan.hints[] 90 | (4 rows) 91 | 92 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.8"; 93 | \dx+ pg_hint_plan 94 | Objects in extension "pg_hint_plan" 95 | Object description 96 | --------------------------------- 97 | sequence hint_plan.hints_id_seq 98 | table hint_plan.hints 99 | type hint_plan.hints 100 | type hint_plan.hints[] 101 | (4 rows) 102 | 103 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.9"; 104 | \dx+ pg_hint_plan 105 | Objects in extension "pg_hint_plan" 106 | Object description 107 | --------------------------------- 108 | sequence hint_plan.hints_id_seq 109 | table hint_plan.hints 110 | type hint_plan.hints 111 | type hint_plan.hints[] 112 | (4 rows) 113 | 114 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.10"; 115 | \dx+ pg_hint_plan 116 | Objects in extension "pg_hint_plan" 117 | Object description 118 | --------------------------------- 119 | sequence hint_plan.hints_id_seq 120 | table hint_plan.hints 121 | type hint_plan.hints 122 | type hint_plan.hints[] 123 | (4 rows) 124 | 125 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4"; 126 | \dx+ pg_hint_plan 127 | Objects in extension "pg_hint_plan" 128 | Object description 129 | --------------------------------- 130 | sequence hint_plan.hints_id_seq 131 | table hint_plan.hints 132 | type hint_plan.hints 133 | type hint_plan.hints[] 134 | (4 rows) 135 | 136 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.1"; 137 | \dx+ pg_hint_plan 138 | Objects in extension "pg_hint_plan" 139 | Object description 140 | --------------------------------- 141 | sequence hint_plan.hints_id_seq 142 | table hint_plan.hints 143 | type hint_plan.hints 144 | type hint_plan.hints[] 145 | (4 rows) 146 | 147 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.2"; 148 | \dx+ pg_hint_plan 149 | Objects in extension "pg_hint_plan" 150 | Object description 151 | --------------------------------- 152 | sequence hint_plan.hints_id_seq 153 | table hint_plan.hints 154 | type hint_plan.hints 155 | type hint_plan.hints[] 156 | (4 rows) 157 | 158 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.3"; 159 | \dx+ pg_hint_plan 160 | Objects in extension "pg_hint_plan" 161 | Object description 162 | --------------------------------- 163 | sequence hint_plan.hints_id_seq 164 | table hint_plan.hints 165 | type hint_plan.hints 166 | type hint_plan.hints[] 167 | (4 rows) 168 | 169 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5"; 170 | \dx+ pg_hint_plan 171 | Objects in extension "pg_hint_plan" 172 | Object description 173 | --------------------------------- 174 | sequence hint_plan.hints_id_seq 175 | table hint_plan.hints 176 | type hint_plan.hints 177 | type hint_plan.hints[] 178 | (4 rows) 179 | 180 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5.1"; 181 | \dx+ pg_hint_plan 182 | Objects in extension "pg_hint_plan" 183 | Object description 184 | --------------------------------- 185 | sequence hint_plan.hints_id_seq 186 | table hint_plan.hints 187 | type hint_plan.hints 188 | type hint_plan.hints[] 189 | (4 rows) 190 | 191 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5.2"; 192 | \dx+ pg_hint_plan 193 | Objects in extension "pg_hint_plan" 194 | Object description 195 | --------------------------------- 196 | sequence hint_plan.hints_id_seq 197 | table hint_plan.hints 198 | type hint_plan.hints 199 | type hint_plan.hints[] 200 | (4 rows) 201 | 202 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.6.0"; 203 | \dx+ pg_hint_plan 204 | Objects in extension "pg_hint_plan" 205 | Object description 206 | --------------------------------- 207 | sequence hint_plan.hints_id_seq 208 | table hint_plan.hints 209 | type hint_plan.hints 210 | type hint_plan.hints[] 211 | (4 rows) 212 | 213 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.6.1"; 214 | \dx+ pg_hint_plan 215 | Objects in extension "pg_hint_plan" 216 | Object description 217 | --------------------------------- 218 | sequence hint_plan.hints_id_seq 219 | table hint_plan.hints 220 | type hint_plan.hints 221 | type hint_plan.hints[] 222 | (4 rows) 223 | 224 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.7.0"; 225 | \dx+ pg_hint_plan 226 | Objects in extension "pg_hint_plan" 227 | Object description 228 | --------------------------------- 229 | sequence hint_plan.hints_id_seq 230 | table hint_plan.hints 231 | type hint_plan.hints 232 | type hint_plan.hints[] 233 | (4 rows) 234 | 235 | \d hint_plan.hints 236 | Table "hint_plan.hints" 237 | Column | Type | Collation | Nullable | Default 238 | ------------------+---------+-----------+----------+---------------------------------- 239 | id | integer | | not null | generated by default as identity 240 | query_id | bigint | | not null | 241 | application_name | text | | not null | 242 | hints | text | | not null | 243 | Indexes: 244 | "hints_pkey" PRIMARY KEY, btree (id) 245 | "hints_id_and_app" UNIQUE, btree (query_id, application_name) 246 | 247 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.8.0"; 248 | \dx+ pg_hint_plan 249 | Objects in extension "pg_hint_plan" 250 | Object description 251 | --------------------------------- 252 | sequence hint_plan.hints_id_seq 253 | table hint_plan.hints 254 | type hint_plan.hints 255 | type hint_plan.hints[] 256 | (4 rows) 257 | 258 | DROP EXTENSION pg_hint_plan; 259 | -------------------------------------------------------------------------------- /expected/ut-T.out: -------------------------------------------------------------------------------- 1 | -- ut-T: tests for table hints 2 | -- This test is focusing on hint retrieval from table 3 | LOAD 'pg_hint_plan'; 4 | SET pg_hint_plan.enable_hint TO on; 5 | SET pg_hint_plan.debug_print TO on; 6 | SET client_min_messages TO LOG; 7 | SET search_path TO public; 8 | -- This hint affects queries with an equivalent query ID when executed as 9 | -- a subquery. 10 | SET pg_hint_plan.enable_hint_table TO on; 11 | SELECT get_query_id('SELECT * FROM t1 WHERE id = 1;') AS query_id \gset 12 | INSERT INTO hint_plan.hints VALUES (DEFAULT, :'query_id', '', 'SeqScan(t1)'); 13 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 14 | -- These queries uses IndexScan without hints 15 | SET pg_hint_plan.enable_hint_table to off; 16 | EXPLAIN (COSTS false) SELECT * FROM t1 WHERE id = 100; 17 | QUERY PLAN 18 | -------------------------------- 19 | Index Scan using t1_pkey on t1 20 | Index Cond: (id = 100) 21 | (2 rows) 22 | 23 | EXPLAIN (COSTS false) EXECUTE p1; 24 | QUERY PLAN 25 | -------------------------------- 26 | Index Scan using t1_pkey on t1 27 | Index Cond: (id = 100) 28 | (2 rows) 29 | 30 | DEALLOCATE p1; 31 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 32 | EXPLAIN (COSTS false) CREATE TABLE ct1 AS EXECUTE p1; 33 | QUERY PLAN 34 | -------------------------------- 35 | Index Scan using t1_pkey on t1 36 | Index Cond: (id = 100) 37 | (2 rows) 38 | 39 | DEALLOCATE p1; 40 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 41 | -- Forced to use SeqScan by table hints 42 | SET pg_hint_plan.enable_hint_table to on; 43 | EXPLAIN (COSTS false) SELECT * FROM t1 WHERE id = 100; 44 | LOG: pg_hint_plan: 45 | used hint: 46 | SeqScan(t1) 47 | not used hint: 48 | duplication hint: 49 | error hint: 50 | 51 | QUERY PLAN 52 | ---------------------- 53 | Seq Scan on t1 54 | Filter: (id = 100) 55 | (2 rows) 56 | 57 | EXPLAIN (COSTS false) EXECUTE p1; 58 | LOG: pg_hint_plan: 59 | used hint: 60 | SeqScan(t1) 61 | not used hint: 62 | duplication hint: 63 | error hint: 64 | 65 | QUERY PLAN 66 | ---------------------- 67 | Seq Scan on t1 68 | Filter: (id = 100) 69 | (2 rows) 70 | 71 | DEALLOCATE p1; 72 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 73 | EXPLAIN (COSTS false) CREATE TABLE ct1 AS EXECUTE p1; 74 | LOG: pg_hint_plan: 75 | used hint: 76 | SeqScan(t1) 77 | not used hint: 78 | duplication hint: 79 | error hint: 80 | 81 | QUERY PLAN 82 | ---------------------- 83 | Seq Scan on t1 84 | Filter: (id = 100) 85 | (2 rows) 86 | 87 | DEALLOCATE p1; 88 | SET pg_hint_plan.enable_hint_table to off; 89 | DELETE FROM hint_plan.hints; 90 | -------------------------------------------------------------------------------- /expected/ut-fdw.out: -------------------------------------------------------------------------------- 1 | -- directory paths and dlsuffix are passed to us in environment variables 2 | \getenv abs_srcdir PG_ABS_SRCDIR 3 | \set filename :abs_srcdir '/data/data.csv' 4 | LOAD 'pg_hint_plan'; 5 | SET search_path TO public; 6 | SET pg_hint_plan.debug_print TO on; 7 | SET client_min_messages TO LOG; 8 | SET pg_hint_plan.enable_hint TO on; 9 | CREATE EXTENSION file_fdw; 10 | CREATE SERVER file_server FOREIGN DATA WRAPPER file_fdw; 11 | CREATE USER MAPPING FOR PUBLIC SERVER file_server; 12 | CREATE FOREIGN TABLE ft1 (id int, val int) SERVER file_server OPTIONS (format 'csv', filename :'filename'); 13 | -- foreign table test 14 | SELECT * FROM ft1; 15 | id | val 16 | ----+----- 17 | 1 | 1 18 | 2 | 2 19 | 3 | 3 20 | 4 | 4 21 | 5 | 5 22 | 6 | 6 23 | 7 | 7 24 | 8 | 8 25 | 9 | 9 26 | 10 | 10 27 | (10 rows) 28 | 29 | \t 30 | SELECT explain_filter(' 31 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 32 | '); 33 | Nested Loop 34 | Join Filter: (t1.c1 = ft_1.id) 35 | -> Nested Loop 36 | Join Filter: (ft_1.id = ft_2.id) 37 | -> Foreign Scan on ft1 ft_1 38 | Foreign File: (snip..) 39 | -> Foreign Scan on ft1 ft_2 40 | Foreign File: (snip..) 41 | -> Index Scan using t1_i1 on t1 42 | Index Cond: (c1 = ft_2.id) 43 | 44 | ---- 45 | ---- No. S-1-5 object type for the hint 46 | ---- 47 | -- No. S-1-5-6 48 | SELECT explain_filter(' 49 | /*+SeqScan(t1)SeqScan(ft_1)SeqScan(ft_2)*/ 50 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 51 | '); 52 | LOG: pg_hint_plan: 53 | used hint: 54 | SeqScan(t1) 55 | not used hint: 56 | SeqScan(ft_1) 57 | SeqScan(ft_2) 58 | duplication hint: 59 | error hint: 60 | 61 | Nested Loop 62 | Join Filter: (t1.c1 = ft_2.id) 63 | -> Hash Join 64 | Hash Cond: (t1.c1 = ft_1.id) 65 | -> Seq Scan on t1 66 | -> Hash 67 | -> Foreign Scan on ft1 ft_1 68 | Foreign File: (snip..) 69 | -> Foreign Scan on ft1 ft_2 70 | Foreign File: (snip..) 71 | 72 | ---- 73 | ---- No. J-1-6 object type for the hint 74 | ---- 75 | -- No. J-1-6-6 76 | SELECT explain_filter(' 77 | /*+MergeJoin(ft_1 ft_2)Leading(ft_1 ft_2 t1)*/ 78 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 79 | '); 80 | LOG: pg_hint_plan: 81 | used hint: 82 | MergeJoin(ft_1 ft_2) 83 | Leading(ft_1 ft_2 t1) 84 | not used hint: 85 | duplication hint: 86 | error hint: 87 | 88 | Nested Loop 89 | Join Filter: (t1.c1 = ft_1.id) 90 | -> Merge Join 91 | Merge Cond: (ft_1.id = ft_2.id) 92 | -> Sort 93 | Sort Key: ft_1.id 94 | -> Foreign Scan on ft1 ft_1 95 | Foreign File: (snip..) 96 | -> Sort 97 | Sort Key: ft_2.id 98 | -> Foreign Scan on ft1 ft_2 99 | Foreign File: (snip..) 100 | -> Index Scan using t1_i1 on t1 101 | Index Cond: (c1 = ft_2.id) 102 | 103 | ---- 104 | ---- No. L-1-6 object type for the hint 105 | ---- 106 | -- No. L-1-6-6 107 | SELECT explain_filter(' 108 | /*+Leading(ft_1 ft_2 t1)*/ 109 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 110 | '); 111 | LOG: pg_hint_plan: 112 | used hint: 113 | Leading(ft_1 ft_2 t1) 114 | not used hint: 115 | duplication hint: 116 | error hint: 117 | 118 | Nested Loop 119 | Join Filter: (t1.c1 = ft_1.id) 120 | -> Nested Loop 121 | Join Filter: (ft_1.id = ft_2.id) 122 | -> Foreign Scan on ft1 ft_1 123 | Foreign File: (snip..) 124 | -> Foreign Scan on ft1 ft_2 125 | Foreign File: (snip..) 126 | -> Index Scan using t1_i1 on t1 127 | Index Cond: (c1 = ft_2.id) 128 | 129 | ---- 130 | ---- No. R-1-6 object type for the hint 131 | ---- 132 | -- No. R-1-6-6 133 | SELECT explain_filter(' 134 | /*+Rows(ft_1 ft_2 #1)Leading(ft_1 ft_2 t1)*/ 135 | EXPLAIN SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 136 | '); 137 | LOG: pg_hint_plan: 138 | used hint: 139 | Leading(ft_1 ft_2 t1) 140 | Rows(ft_1 ft_2 #1) 141 | not used hint: 142 | duplication hint: 143 | error hint: 144 | 145 | Nested Loop (cost=xxx..xxx rows=1 width=xxx) 146 | Join Filter: (t1.c1 = ft_1.id) 147 | -> Nested Loop (cost=xxx..xxx rows=1 width=xxx) 148 | Join Filter: (ft_1.id = ft_2.id) 149 | -> Foreign Scan on ft1 ft_1 (cost=xxx..xxx rows=1 width=xxx) 150 | Foreign File: (snip..) 151 | Foreign File Size: 42 b 152 | -> Foreign Scan on ft1 ft_2 (cost=xxx..xxx rows=1 width=xxx) 153 | Foreign File: (snip..) 154 | Foreign File Size: 42 b 155 | -> Index Scan using t1_i1 on t1 (cost=xxx..xxx rows=1 width=xxx) 156 | Index Cond: (c1 = ft_2.id) 157 | 158 | -------------------------------------------------------------------------------- /expected/ut-fini.out: -------------------------------------------------------------------------------- 1 | DROP ROLE IF EXISTS regress_super_user; 2 | DROP ROLE IF EXISTS regress_normal_user; 3 | DROP EXTENSION pg_hint_plan; 4 | -------------------------------------------------------------------------------- /expected/ut-init.out: -------------------------------------------------------------------------------- 1 | SET search_path TO public; 2 | CREATE EXTENSION btree_gist; 3 | CREATE EXTENSION btree_gin; 4 | CREATE ROLE regress_super_user 5 | SUPERUSER 6 | NOCREATEDB 7 | NOCREATEROLE 8 | NOINHERIT 9 | NOLOGIN 10 | NOREPLICATION 11 | CONNECTION LIMIT 1; 12 | CREATE ROLE regress_normal_user 13 | NOSUPERUSER 14 | NOCREATEDB 15 | NOCREATEROLE 16 | NOINHERIT 17 | NOLOGIN 18 | NOREPLICATION 19 | CONNECTION LIMIT 1; 20 | CREATE SCHEMA s1; 21 | CREATE SCHEMA s2; 22 | CREATE TABLE s1.t1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1)); 23 | CREATE TABLE s1.t2 (LIKE s1.t1 INCLUDING ALL); 24 | CREATE TABLE s1.t3 (LIKE s1.t1 INCLUDING ALL); 25 | CREATE TABLE s1.t4 (LIKE s1.t1 INCLUDING ALL); 26 | CREATE TABLE s1.t5 (LIKE s1.t1 INCLUDING ALL); 27 | CREATE TABLE s1.t6 (LIKE s1.t1 INCLUDING ALL); 28 | CREATE TABLE s2.t1 (LIKE s1.t1 INCLUDING ALL); 29 | CREATE TABLE s1.p1 (LIKE s1.t1 INCLUDING ALL); 30 | CREATE UNIQUE INDEX p1_parent ON s1.p1 USING btree (c4 COLLATE "C" varchar_ops ASC NULLS LAST, (c1 * 2 < 100)) WHERE c1 < 10; 31 | CREATE TABLE s1.p2 (LIKE s1.t1 INCLUDING ALL); 32 | CREATE TABLE s1.p1c1 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 <= 100)) INHERITS(s1.p1); 33 | NOTICE: merging column "c1" with inherited definition 34 | NOTICE: merging column "c2" with inherited definition 35 | NOTICE: merging column "c3" with inherited definition 36 | NOTICE: merging column "c4" with inherited definition 37 | CREATE TABLE s1.p1c2 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 200)) INHERITS(s1.p1); 38 | NOTICE: merging column "c1" with inherited definition 39 | NOTICE: merging column "c2" with inherited definition 40 | NOTICE: merging column "c3" with inherited definition 41 | NOTICE: merging column "c4" with inherited definition 42 | CREATE TABLE s1.p1c3 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 > 200)) INHERITS(s1.p1); 43 | NOTICE: merging column "c1" with inherited definition 44 | NOTICE: merging column "c2" with inherited definition 45 | NOTICE: merging column "c3" with inherited definition 46 | NOTICE: merging column "c4" with inherited definition 47 | CREATE TABLE s1.p2c1 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 <= 100)) INHERITS(s1.p2); 48 | NOTICE: merging column "c1" with inherited definition 49 | NOTICE: merging column "c2" with inherited definition 50 | NOTICE: merging column "c3" with inherited definition 51 | NOTICE: merging column "c4" with inherited definition 52 | CREATE TABLE s1.p2c2 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 200)) INHERITS(s1.p2); 53 | NOTICE: merging column "c1" with inherited definition 54 | NOTICE: merging column "c2" with inherited definition 55 | NOTICE: merging column "c3" with inherited definition 56 | NOTICE: merging column "c4" with inherited definition 57 | CREATE TABLE s1.p2c3 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 > 200)) INHERITS(s1.p2); 58 | NOTICE: merging column "c1" with inherited definition 59 | NOTICE: merging column "c2" with inherited definition 60 | NOTICE: merging column "c3" with inherited definition 61 | NOTICE: merging column "c4" with inherited definition 62 | CREATE TABLE s1.p2c1c1 (LIKE s1.p2c1 INCLUDING ALL, CHECK (c1 <= 50)) INHERITS(s1.p2c1); 63 | NOTICE: merging column "c1" with inherited definition 64 | NOTICE: merging column "c2" with inherited definition 65 | NOTICE: merging column "c3" with inherited definition 66 | NOTICE: merging column "c4" with inherited definition 67 | NOTICE: merging constraint "p2c1_c1_check" with inherited definition 68 | CREATE TABLE s1.p2c1c2 (LIKE s1.p2c1 INCLUDING ALL, CHECK (c1 > 50 AND c1 <= 100)) INHERITS(s1.p2c1); 69 | NOTICE: merging column "c1" with inherited definition 70 | NOTICE: merging column "c2" with inherited definition 71 | NOTICE: merging column "c3" with inherited definition 72 | NOTICE: merging column "c4" with inherited definition 73 | NOTICE: merging constraint "p2c1_c1_check" with inherited definition 74 | CREATE TABLE s1.p2c2c1 (LIKE s1.p2c2 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 150)) INHERITS(s1.p2c2); 75 | NOTICE: merging column "c1" with inherited definition 76 | NOTICE: merging column "c2" with inherited definition 77 | NOTICE: merging column "c3" with inherited definition 78 | NOTICE: merging column "c4" with inherited definition 79 | NOTICE: merging constraint "p2c2_c1_check" with inherited definition 80 | CREATE TABLE s1.p2c2c2 (LIKE s1.p2c2 INCLUDING ALL, CHECK (c1 > 150 AND c1 <= 200)) INHERITS(s1.p2c2); 81 | NOTICE: merging column "c1" with inherited definition 82 | NOTICE: merging column "c2" with inherited definition 83 | NOTICE: merging column "c3" with inherited definition 84 | NOTICE: merging column "c4" with inherited definition 85 | NOTICE: merging constraint "p2c2_c1_check" with inherited definition 86 | CREATE TABLE s1.p2c3c1 (LIKE s1.p2c3 INCLUDING ALL, CHECK (c1 > 200 AND c1 <= 250)) INHERITS(s1.p2c3); 87 | NOTICE: merging column "c1" with inherited definition 88 | NOTICE: merging column "c2" with inherited definition 89 | NOTICE: merging column "c3" with inherited definition 90 | NOTICE: merging column "c4" with inherited definition 91 | NOTICE: merging constraint "p2c3_c1_check" with inherited definition 92 | CREATE TABLE s1.p2c3c2 (LIKE s1.p2c3 INCLUDING ALL, CHECK (c1 > 250)) INHERITS(s1.p2c3); 93 | NOTICE: merging column "c1" with inherited definition 94 | NOTICE: merging column "c2" with inherited definition 95 | NOTICE: merging column "c3" with inherited definition 96 | NOTICE: merging column "c4" with inherited definition 97 | NOTICE: merging constraint "p2c3_c1_check" with inherited definition 98 | CREATE TABLE s1.r1 (LIKE s1.t1); 99 | CREATE TABLE s1.r2 (LIKE s1.t1); 100 | CREATE TABLE s1.r3 (LIKE s1.t1); 101 | CREATE TABLE s1.r4 (LIKE s1.t1); 102 | CREATE TABLE s1.r5 (LIKE s1.t1); 103 | CREATE TABLE s1.r1_ (LIKE s1.t1); 104 | CREATE TABLE s1.r2_ (LIKE s1.t1); 105 | CREATE TABLE s1.r3_ (LIKE s1.t1); 106 | CREATE TABLE s1.ti1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1), UNIQUE (c2)); 107 | CREATE TABLE s1.pt1 (c1 int, c2 int, c3 int, c4 int) PARTITION BY RANGE (c1); 108 | CREATE TABLE s1.pt1_c1 PARTITION OF s1.pt1 FOR VALUES FROM (MINVALUE) TO (101); 109 | CREATE TABLE s1.pt1_c2 PARTITION OF s1.pt1 FOR VALUES FROM (101) TO (201); 110 | CREATE TABLE s1.pt1_c3 PARTITION OF s1.pt1 FOR VALUES FROM (201) TO (MAXVALUE); 111 | CREATE UNLOGGED TABLE s1.ul1 (LIKE s1.t1 INCLUDING ALL); 112 | INSERT INTO s1.t1 SELECT i, i, i % 100, i FROM (SELECT generate_series(1, 1000) i) t; 113 | INSERT INTO s1.t2 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 114 | INSERT INTO s2.t1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 115 | INSERT INTO s1.p1c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 116 | INSERT INTO s1.p1c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(101, 200) i) t; 117 | INSERT INTO s1.p1c3 SELECT i, i, i % 10, i FROM (SELECT generate_series(201, 300) i) t; 118 | INSERT INTO s1.p2c1c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 50) i) t; 119 | INSERT INTO s1.p2c1c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(51, 100) i) t; 120 | INSERT INTO s1.p2c2c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(101, 150) i) t; 121 | INSERT INTO s1.p2c2c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(151, 200) i) t; 122 | INSERT INTO s1.p2c3c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(201, 250) i) t; 123 | INSERT INTO s1.p2c3c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(251, 300) i) t; 124 | INSERT INTO s1.ti1 SELECT i, i, i % 100, i FROM (SELECT generate_series(1, 1000) i) t; 125 | INSERT INTO s1.pt1 SELECT i, i, i % 10, i FROM (SELECT generate_series(0, 300) i) t; 126 | CREATE INDEX t1_i ON s1.t1 (c3); 127 | CREATE INDEX t1_i1 ON s1.t1 (c1); 128 | CREATE INDEX t2_i1 ON s1.t2 (c1); 129 | CREATE INDEX t3_i1 ON s1.t3 (c1); 130 | CREATE INDEX t4_i1 ON s1.t4 (c1); 131 | CREATE INDEX p1_i ON s1.p1 (c1); 132 | CREATE INDEX p2_i ON s1.p2 (c1); 133 | CREATE INDEX p1_i2 ON s1.p1 (c2); 134 | CREATE INDEX p1c1_i ON s1.p1c1 (c1); 135 | CREATE INDEX p1c2_i ON s1.p1c2 (c1); 136 | CREATE INDEX p1c3_i ON s1.p1c3 (c1); 137 | CREATE INDEX p2c1_i ON s1.p2c1 (c1); 138 | CREATE INDEX p2c2_i ON s1.p2c2 (c1); 139 | CREATE INDEX p2c3_i ON s1.p2c3 (c1); 140 | CREATE INDEX p2c1c1_i ON s1.p2c1c1 (c1); 141 | CREATE INDEX p2c1c2_i ON s1.p2c1c2 (c1); 142 | CREATE INDEX p2c2c1_i ON s1.p2c2c1 (c1); 143 | CREATE INDEX p2c2c2_i ON s1.p2c2c2 (c1); 144 | CREATE INDEX p2c3c1_i ON s1.p2c3c1 (c1); 145 | CREATE INDEX p2c3c2_i ON s1.p2c3c2 (c1); 146 | CREATE INDEX ti1_i1 ON s1.ti1 (c2); 147 | CREATE INDEX ti1_i2 ON s1.ti1 (c2, c4); 148 | CREATE INDEX ti1_i3 ON s1.ti1 (c2, c4, c4); 149 | CREATE INDEX ti1_i4 ON s1.ti1 (c2, c4, c4, c4); 150 | CREATE INDEX ti1_btree ON s1.ti1 USING btree (c1); 151 | CREATE INDEX ti1_hash ON s1.ti1 USING hash (c1); 152 | CREATE INDEX ti1_gist ON s1.ti1 USING gist (c1); 153 | CREATE INDEX ti1_gin ON s1.ti1 USING gin (c1); 154 | CREATE INDEX ti1_expr ON s1.ti1 ((c1 < 100)); 155 | CREATE INDEX ti1_pred ON s1.ti1 (lower(c4)); 156 | CREATE UNIQUE INDEX ti1_uniq ON s1.ti1 (c1); 157 | CREATE INDEX ti1_multi ON s1.ti1 (c1, c2, c3, c4); 158 | CREATE INDEX ti1_ts ON s1.ti1 USING gin(to_tsvector('english', c4)); 159 | CREATE INDEX pt1_c1_c2_i ON s1.pt1_c1(c2); 160 | CREATE INDEX pt1_c1_c3_i ON s1.pt1_c1(c3); 161 | CREATE INDEX pt1_c2_c2_i ON s1.pt1_c2(c2); 162 | CREATE INDEX pt1_c2_c3_i ON s1.pt1_c2(c3); 163 | CREATE INDEX pt1_c3_c2_i ON s1.pt1_c3(c2); 164 | CREATE INDEX pt1_c3_c3_i ON s1.pt1_c3(c3); 165 | CREATE VIEW s1.v1 AS SELECT v1t1.c1, v1t1.c2, v1t1.c3, v1t1.c4 FROM s1.t1 v1t1; 166 | CREATE VIEW s1.v1_ AS SELECT v1t1_.c1, v1t1_.c2, v1t1_.c3, v1t1_.c4 FROM s1.t1 v1t1_; 167 | CREATE VIEW s1.v2 AS SELECT v2t1.c1, v2t1.c2, v2t1.c3, v2t1.c4 FROM s1.t1 v2t1 JOIN s1.t2 v2t2 ON(v2t1.c1 = v2t2.c1); 168 | CREATE VIEW s1.v3 AS SELECT v3t1.c1, v3t1.c2, v3t1.c3, v3t1.c4 FROM s1.t1 v3t1 JOIN s1.t2 v3t2 ON(v3t1.c1 = v3t2.c1) JOIN s1.t3 v3t3 ON(v3t1.c1 = v3t3.c1); 169 | ANALYZE s1.t1; 170 | ANALYZE s1.t2; 171 | ANALYZE s2.t1; 172 | ANALYZE s1.p1; 173 | ANALYZE s1.p2; 174 | ANALYZE s1.p1c1; 175 | ANALYZE s1.p1c2; 176 | ANALYZE s1.p1c3; 177 | ANALYZE s1.p2c1c1; 178 | ANALYZE s1.p2c1c2; 179 | ANALYZE s1.p2c2c1; 180 | ANALYZE s1.p2c2c2; 181 | ANALYZE s1.p2c3c1; 182 | ANALYZE s1.p2c3c2; 183 | ANALYZE s1.ti1; 184 | ANALYZE s1.pt1; 185 | ANALYZE s1.t5; 186 | ANALYZE s1.t6; 187 | CREATE FUNCTION s1.f1 () RETURNS s1.t1 AS $$ 188 | VALUES(1,1,1,'1'), (2,2,2,'2'), (3,3,3,'3') 189 | $$ LANGUAGE sql; 190 | CREATE RULE r1 AS ON UPDATE TO s1.r1 DO INSTEAD ( 191 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 192 | ); 193 | CREATE RULE r2 AS ON UPDATE TO s1.r2 DO INSTEAD ( 194 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 195 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 196 | ); 197 | CREATE RULE r3 AS ON UPDATE TO s1.r3 DO INSTEAD ( 198 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 199 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 200 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 201 | ); 202 | CREATE RULE r1_ AS ON UPDATE TO s1.r1_ DO INSTEAD ( 203 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 204 | ); 205 | CREATE RULE r2_ AS ON UPDATE TO s1.r2_ DO INSTEAD ( 206 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 207 | SELECT max(b2t1.c1) FROM s1.t1 b2t1, s1.t2 b2t2, s1.t3 b2t3, s1.t4 b2t4 WHERE b2t1.ctid = '(1,1)' AND b2t1.c1 = b2t2.c1 AND b2t2.ctid = '(1,1)' AND b2t1.c1 = b2t3.c1 AND b2t3.ctid = '(1,1)' AND b2t1.c1 = b2t4.c1 AND b2t4.ctid = '(1,1)'; 208 | ); 209 | CREATE RULE r3_ AS ON UPDATE TO s1.r3_ DO INSTEAD ( 210 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 211 | SELECT max(b2t1.c1) FROM s1.t1 b2t1, s1.t2 b2t2, s1.t3 b2t3, s1.t4 b2t4 WHERE b2t1.ctid = '(1,1)' AND b2t1.c1 = b2t2.c1 AND b2t2.ctid = '(1,1)' AND b2t1.c1 = b2t3.c1 AND b2t3.ctid = '(1,1)' AND b2t1.c1 = b2t4.c1 AND b2t4.ctid = '(1,1)'; 212 | SELECT max(b3t1.c1) FROM s1.t1 b3t1, s1.t2 b3t2, s1.t3 b3t3, s1.t4 b3t4 WHERE b3t1.ctid = '(1,1)' AND b3t1.c1 = b3t2.c1 AND b3t2.ctid = '(1,1)' AND b3t1.c1 = b3t3.c1 AND b3t3.ctid = '(1,1)' AND b3t1.c1 = b3t4.c1 AND b3t4.ctid = '(1,1)'; 213 | ); 214 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.0--1.3.1.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.0--1.3.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.1'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.0.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION pg_hint_plan" to load this file. \quit 5 | 6 | CREATE TABLE hint_plan.hints ( 7 | id serial NOT NULL, 8 | norm_query_string text NOT NULL, 9 | application_name text NOT NULL, 10 | hints text NOT NULL, 11 | PRIMARY KEY (id) 12 | ); 13 | CREATE UNIQUE INDEX hints_norm_and_app ON hint_plan.hints ( 14 | norm_query_string, 15 | application_name 16 | ); 17 | 18 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 19 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 20 | 21 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 22 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 23 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.1--1.3.2.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.1--1.3.2.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.2'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.10--1.4.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.10--1.4.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.4'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.2--1.3.3.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.2--1.3.3.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.3'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.3--1.3.4.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.3--1.3.4.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.4'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.4--1.3.5.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.4--1.3.5.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.5'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.5--1.3.6.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.5--1.3.6.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.6'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.6--1.3.7.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.6--1.3.7.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.7'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.7--1.3.8.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.7--1.3.8.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.8'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.8--1.3.9.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.8--1.3.9.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.9'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.3.9--1.3.10.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.3.9--1.3.10.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.3.10'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.4--1.4.1.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.4--1.4.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.4.1'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.4.1--1.4.2.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.4.1--1.4.2.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.4.2'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.4.2--1.4.3.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.4.2--1.4.3.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.4.3'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.4.3--1.5.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.4.3--1.5.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.5'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.5--1.5.1.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.5--1.5.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.5.1'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.5.1--1.5.2.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.5.1--1.5.2.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.5.2'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.5.2--1.6.0.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.5.2--1.6.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.6.0'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints',''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq',''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.6.0--1.6.1.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.6.0--1.6.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.6.1'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints', ''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq', ''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan--1.6.1--1.7.0.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.6.1--1.7.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.7.0'" to load this file. \quit 5 | 6 | -- Hint table uses query IDs since 1.7.0, so drop the old one that depends 7 | -- on query strings and re-create it. 8 | DROP TABLE hint_plan.hints; 9 | CREATE TABLE hint_plan.hints ( 10 | id int PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 11 | query_id bigint NOT NULL, 12 | application_name text NOT NULL, 13 | hints text NOT NULL 14 | ); 15 | CREATE UNIQUE INDEX hints_id_and_app 16 | ON hint_plan.hints (query_id, application_name); 17 | 18 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints', ''); 19 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq', ''); 20 | 21 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 22 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 23 | -------------------------------------------------------------------------------- /pg_hint_plan--1.7.0--1.8.0.sql: -------------------------------------------------------------------------------- 1 | /* pg_hint_plan/pg_hint_plan--1.7.0--1.8.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "ALTER EXTENSION pg_hint_plan UPDATE TO '1.8.0'" to load this file. \quit 5 | 6 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints', ''); 7 | SELECT pg_catalog.pg_extension_config_dump('hint_plan.hints_id_seq', ''); 8 | 9 | GRANT SELECT ON hint_plan.hints TO PUBLIC; 10 | GRANT USAGE ON SCHEMA hint_plan TO PUBLIC; 11 | -------------------------------------------------------------------------------- /pg_hint_plan.control: -------------------------------------------------------------------------------- 1 | # pg_hint_plan extension 2 | 3 | comment = 'optimizer hints for PostgreSQL' 4 | default_version = '1.8.0' 5 | relocatable = false 6 | schema = hint_plan 7 | -------------------------------------------------------------------------------- /query_scan.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * query_scan.h 4 | * lexical scanner for SQL commands 5 | * 6 | * This lexer can be used to extra hints from query contents, taking into 7 | * account what the backend would consider as values, for example. 8 | * 9 | * Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group 10 | * Portions Copyright (c) 1994, Regents of the University of California 11 | * 12 | * query_scan.h 13 | * 14 | *------------------------------------------------------------------------- 15 | */ 16 | #ifndef QUERY_SCAN_H 17 | #define QUERY_SCAN_H 18 | 19 | #include "lib/stringinfo.h" 20 | 21 | /* Abstract type for lexer's internal state */ 22 | typedef struct QueryScanStateData *QueryScanState; 23 | 24 | /* Termination states for query_scan() */ 25 | typedef enum 26 | { 27 | QUERY_SCAN_INCOMPLETE, /* end of line, SQL statement incomplete */ 28 | QUERY_SCAN_EOL /* end of line, SQL possibly complete */ 29 | } QueryScanResult; 30 | 31 | extern QueryScanState query_scan_create(void); 32 | extern void query_scan_setup(QueryScanState state, 33 | const char *line, int line_len, 34 | int encoding, bool std_strings, 35 | int elevel); 36 | extern void query_scan_finish(QueryScanState state); 37 | extern QueryScanResult query_scan(QueryScanState state, 38 | StringInfo query_buf); 39 | 40 | #endif /* QUERY_SCAN_H */ 41 | -------------------------------------------------------------------------------- /query_scan_int.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * query_scan_int.h 4 | * lexical scanner internal declarations 5 | * 6 | * This file declares the QueryScanStateData structure used by query_scan.l. 7 | * 8 | * One difficult aspect of this code is that we need to work in multibyte 9 | * encodings that are not ASCII-safe. A "safe" encoding is one in which each 10 | * byte of a multibyte character has the high bit set (it's >= 0x80). Since 11 | * all our lexing rules treat all high-bit-set characters alike, we don't 12 | * really need to care whether such a byte is part of a sequence or not. 13 | * In an "unsafe" encoding, we still expect the first byte of a multibyte 14 | * sequence to be >= 0x80, but later bytes might not be. If we scan such 15 | * a sequence as-is, the lexing rules could easily be fooled into matching 16 | * such bytes to ordinary ASCII characters. Our solution for this is to 17 | * substitute 0xFF for each non-first byte within the data presented to flex. 18 | * The flex rules will then pass the FF's through unmolested. The 19 | * query_scan_emit() subroutine is responsible for looking back to the 20 | * original string and replacing FF's with the corresponding original bytes. 21 | * 22 | * Another interesting thing we do here is scan different parts of the same 23 | * input with physically separate flex lexers (ie, lexers written in separate 24 | * .l files). We can get away with this because the only part of the 25 | * persistent state of a flex lexer that depends on its parsing rule tables 26 | * is the start state number, which is easy enough to manage --- usually, 27 | * in fact, we just need to set it to INITIAL when changing lexers. But to 28 | * make that work at all, we must use re-entrant lexers, so that all the 29 | * relevant state is in the yyscan_t attached to the QueryScanState; 30 | * if we were using lexers with separate static state we would soon end up 31 | * with dangling buffer pointers in one or the other. Also note that this 32 | * is unlikely to work very nicely if the lexers aren't all built with the 33 | * same flex version, or if they don't use the same flex options. 34 | * 35 | * 36 | * Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group 37 | * Portions Copyright (c) 1994, Regents of the University of California 38 | * 39 | * query_scan_int.h 40 | * 41 | *------------------------------------------------------------------------- 42 | */ 43 | #ifndef QUERY_SCAN_INT_H 44 | #define QUERY_SCAN_INT_H 45 | 46 | #include "query_scan.h" 47 | 48 | /* 49 | * These are just to allow this file to be compilable standalone for header 50 | * validity checking; in actual use, this file should always be included 51 | * from the body of a flex file, where these symbols are already defined. 52 | */ 53 | #ifndef YY_TYPEDEF_YY_BUFFER_STATE 54 | #define YY_TYPEDEF_YY_BUFFER_STATE 55 | typedef struct yy_buffer_state *YY_BUFFER_STATE; 56 | #endif 57 | #ifndef YY_TYPEDEF_YY_SCANNER_T 58 | #define YY_TYPEDEF_YY_SCANNER_T 59 | typedef void *yyscan_t; 60 | #endif 61 | 62 | /* 63 | * All working state of the lexer must be stored in QueryScanStateData 64 | * between calls. This allows us to have multiple open lexer operations, 65 | * which is needed for nested include files. The lexer itself is not 66 | * recursive, but it must be re-entrant. 67 | */ 68 | typedef struct QueryScanStateData 69 | { 70 | yyscan_t scanner; /* Flex's state for this QueryScanState */ 71 | 72 | StringInfo output_buf; /* current output buffer */ 73 | 74 | int elevel; /* level of reports generated at parsing */ 75 | 76 | /* 77 | * These variables always refer to the outer buffer, never to any stacked 78 | * variable-expansion buffer. 79 | */ 80 | YY_BUFFER_STATE scanbufhandle; 81 | char *scanbuf; /* start of outer-level input buffer */ 82 | const char *scanline; /* current input line at outer level */ 83 | 84 | /* safe_encoding, curline, refline are used by emit() to replace FFs */ 85 | int encoding; /* encoding being used now */ 86 | bool safe_encoding; /* is current encoding "safe"? */ 87 | bool std_strings; /* are string literals standard? */ 88 | const char *curline; /* actual flex input string for cur buf */ 89 | const char *refline; /* original data for cur buffer */ 90 | 91 | /* 92 | * All this state lives across successive input lines. start_state is 93 | * adopted by yylex() on entry, and updated with its finishing state on 94 | * exit. 95 | */ 96 | int start_state; /* yylex's starting/finishing state */ 97 | int state_before_str_stop; /* start cond. before end quote */ 98 | int paren_depth; /* depth of nesting in parentheses */ 99 | int xcdepth; /* depth of nesting in slash-star comments */ 100 | char *dolqstart; /* current $foo$ quote start string */ 101 | int xhintnum; /* number of query hints found */ 102 | 103 | /* 104 | * State to track boundaries of BEGIN ... END blocks in function 105 | * definitions, so that semicolons do not send query too early. 106 | */ 107 | int identifier_count; /* identifiers since start of statement */ 108 | char identifiers[4]; /* records the first few identifiers */ 109 | int begin_depth; /* depth of begin/end pairs */ 110 | } QueryScanStateData; 111 | 112 | 113 | extern YY_BUFFER_STATE query_scan_prepare_buffer(QueryScanState state, 114 | const char *txt, int len, 115 | char **txtcopy); 116 | extern void query_yyerror(int elevel, const char *txt, const char *message); 117 | 118 | extern void query_scan_emit(QueryScanState state, const char *txt, int len); 119 | 120 | #endif /* QUERY_SCAN_INT_H */ 121 | -------------------------------------------------------------------------------- /sql/base_plan.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO public; 2 | 3 | -- query type 1 4 | EXPLAIN (COSTS false) SELECT * FROM t1, t2 WHERE t1.id = t2.id; 5 | -- query type 2 6 | EXPLAIN (COSTS false) SELECT * FROM t1, t4 WHERE t1.val < 10; 7 | -- query type 3 8 | EXPLAIN (COSTS false) SELECT * FROM t3, t4 WHERE t3.id = t4.id AND t4.ctid = '(1,1)'; 9 | -- query type 4 10 | EXPLAIN (COSTS false) SELECT * FROM t1, t2 WHERE t1.id = t2.id AND t1.ctid = '(1,1)'; 11 | -- query type 5 12 | EXPLAIN (COSTS false) SELECT * FROM t1, t3 WHERE t1.val = t3.val; 13 | -- query type 6 14 | EXPLAIN (COSTS false) SELECT * FROM t1, t2, t3, t4 WHERE t1.id = t2.id AND t1.id = t3.id AND t1.id = t4.id; 15 | -------------------------------------------------------------------------------- /sql/hint_table.sql: -------------------------------------------------------------------------------- 1 | -- Tests for the hint table 2 | LOAD 'pg_hint_plan'; 3 | 4 | -- Attempting to use the hint table without the extension created 5 | -- emits a WARNING. 6 | SET pg_hint_plan.enable_hint_table TO on; 7 | SELECT 1; 8 | SET pg_hint_plan.enable_hint_table TO off; 9 | 10 | CREATE EXTENSION pg_hint_plan; 11 | SET pg_hint_plan.enable_hint_table TO on; 12 | SELECT 1; 13 | SET pg_hint_plan.enable_hint_table TO off; 14 | DROP EXTENSION pg_hint_plan; 15 | -------------------------------------------------------------------------------- /sql/init.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO public; 2 | 3 | CREATE EXTENSION pg_hint_plan; 4 | CREATE SCHEMA s0; 5 | 6 | CREATE TABLE t1 (id int PRIMARY KEY, val int); 7 | CREATE TABLE t2 (id int PRIMARY KEY, val int); 8 | CREATE TABLE t3 (id int PRIMARY KEY, val int); 9 | CREATE TABLE t4 (id int PRIMARY KEY, val int); 10 | CREATE TABLE t5 (id int PRIMARY KEY, val int); 11 | CREATE TABLE p1 (id int PRIMARY KEY, val int); 12 | CREATE TABLE p1_c1 (LIKE p1 INCLUDING ALL, CHECK (id <= 100)) INHERITS(p1); 13 | CREATE TABLE p1_c2 (LIKE p1 INCLUDING ALL, CHECK (id > 100 AND id <= 200)) INHERITS(p1); 14 | CREATE TABLE p1_c3 (LIKE p1 INCLUDING ALL, CHECK (id > 200 AND id <= 300)) INHERITS(p1); 15 | CREATE TABLE p1_c4 (LIKE p1 INCLUDING ALL, CHECK (id > 300)) INHERITS(p1); 16 | CREATE TABLE p1_c1_c1 (LIKE p1 INCLUDING ALL, CHECK (id <= 50)) INHERITS(p1_c1); 17 | CREATE TABLE p1_c1_c2 (LIKE p1 INCLUDING ALL, CHECK (id > 50 AND id <= 100)) INHERITS(p1_c1); 18 | CREATE TABLE p1_c3_c1 (LIKE p1 INCLUDING ALL, CHECK (id > 200 AND id <= 250)) INHERITS(p1_c3); 19 | CREATE TABLE p1_c3_c2 (LIKE p1 INCLUDING ALL, CHECK (id > 250 AND id <= 300)) INHERITS(p1_c3); 20 | CREATE TABLE p2 (id int PRIMARY KEY, val text); 21 | CREATE INDEX p2_id_val_idx ON p2 (id, val); 22 | CREATE UNIQUE INDEX p2_val_idx ON p2 (val); 23 | CREATE INDEX p2_ununi_id_val_idx ON p2 (val); 24 | CREATE INDEX p2_val_idx_1 ON p2 USING hash (val); 25 | CREATE INDEX p2_val_id_idx ON p2 (val, id); 26 | CREATE INDEX p2_val_idx2 ON p2 (val COLLATE "C"); 27 | CREATE INDEX p2_val_idx3 ON p2 (val varchar_ops); 28 | CREATE INDEX p2_val_idx4 ON p2 (val DESC NULLS LAST); 29 | CREATE INDEX p2_val_idx5 ON p2 (val NULLS FIRST); 30 | CREATE INDEX p2_expr ON p2 ((val < '120')); 31 | CREATE INDEX p2_expr2 ON p2 ((id * 2 < 120)); 32 | CREATE INDEX p2_val_idx6 ON p2 (val) WHERE val >= '50' AND val < '51'; 33 | CREATE INDEX p2_val_idx7 ON p2 (val) WHERE id < 120; 34 | CREATE TABLE p2_c1 (LIKE p2 INCLUDING ALL, CHECK (id <= 100)) INHERITS(p2); 35 | CREATE TABLE p2_c2 (LIKE p2 INCLUDING ALL, CHECK (id > 100 AND id <= 200)) INHERITS(p2); 36 | CREATE TABLE p2_c3 (LIKE p2 INCLUDING ALL, CHECK (id > 200 AND id <= 300)) INHERITS(p2); 37 | CREATE TABLE p2_c4 (LIKE p2 INCLUDING ALL, CHECK (id > 300)) INHERITS(p2); 38 | CREATE TABLE p2_c1_c1 (LIKE p2 INCLUDING ALL, CHECK (id <= 50)) INHERITS(p2_c1); 39 | CREATE TABLE p2_c1_c2 (LIKE p2 INCLUDING ALL, CHECK (id > 50 AND id <= 100)) INHERITS(p2_c1); 40 | CREATE TABLE p2_c3_c1 (LIKE p2 INCLUDING ALL, CHECK (id > 200 AND id <= 250)) INHERITS(p2_c3); 41 | CREATE TABLE p2_c3_c2 (LIKE p2 INCLUDING ALL, CHECK (id > 250 AND id <= 300)) INHERITS(p2_c3); 42 | CREATE TABLE s0.t1 (id int PRIMARY KEY, val int); 43 | 44 | INSERT INTO t1 SELECT i, i % 100 FROM (SELECT generate_series(1, 10000) i) t; 45 | INSERT INTO t2 SELECT i, i % 10 FROM (SELECT generate_series(1, 1000) i) t; 46 | INSERT INTO t3 SELECT i, i FROM (SELECT generate_series(1, 100) i) t; 47 | INSERT INTO t4 SELECT i, i FROM (SELECT generate_series(1, 10) i) t; 48 | INSERT INTO t5 SELECT i, i % 100 FROM (SELECT generate_series(1, 10000) i) t; 49 | INSERT INTO p1_c1_c1 SELECT i, i % 100 FROM (SELECT generate_series(1, 50) i) t; 50 | INSERT INTO p1_c1_c2 SELECT i, i % 100 FROM (SELECT generate_series(51, 100) i) t; 51 | INSERT INTO p1_c2 SELECT i, i % 100 FROM (SELECT generate_series(101, 200) i) t; 52 | INSERT INTO p1_c3_c1 SELECT i, i % 100 FROM (SELECT generate_series(201, 250) i) t; 53 | INSERT INTO p1_c3_c2 SELECT i, i % 100 FROM (SELECT generate_series(251, 300) i) t; 54 | INSERT INTO p1_c4 SELECT i, i % 100 FROM (SELECT generate_series(301, 400) i) t; 55 | INSERT INTO p2_c1_c1 SELECT i, i % 100 FROM (SELECT generate_series(1, 50) i) t; 56 | INSERT INTO p2_c1_c2 SELECT i, i % 100 FROM (SELECT generate_series(51, 100) i) t; 57 | INSERT INTO p2_c2 SELECT i, i % 100 FROM (SELECT generate_series(101, 200) i) t; 58 | INSERT INTO p2_c3_c1 SELECT i, i % 100 FROM (SELECT generate_series(201, 250) i) t; 59 | INSERT INTO p2_c3_c2 SELECT i, i % 100 FROM (SELECT generate_series(251, 300) i) t; 60 | INSERT INTO p2_c4 SELECT i, i % 100 FROM (SELECT generate_series(301, 400) i) t; 61 | 62 | CREATE INDEX t1_val ON t1 (val); 63 | CREATE INDEX t2_val ON t2 (val); 64 | CREATE INDEX t5_id1 ON t5 (id); 65 | CREATE INDEX t5_id2 ON t5 (id); 66 | CREATE INDEX t5_id3 ON t5 (id); 67 | CREATE INDEX t5_val ON t5 (val); 68 | DROP INDEX p2_c4_val_id_idx; 69 | CREATE INDEX p2_id2_val ON p2 (id, id, val); 70 | CREATE INDEX p2_c1_id2_val ON p2_c1 (id, id, val); 71 | CREATE INDEX p2_c2_id2_val ON p2_c2 (id, id, val); 72 | CREATE INDEX p2_val2_id ON p2 (val, id, val); 73 | CREATE INDEX t5_idaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa ON t5 (id); 74 | CREATE INDEX p1_val1 ON p1 (val); 75 | CREATE INDEX p1_val2 ON p1 (val); 76 | CREATE INDEX p1_val3 ON p1 (val); 77 | CREATE INDEX p1_c1_val1 ON p1_c1 (val); 78 | CREATE INDEX p1_c1_val2 ON p1_c1 (val); 79 | CREATE INDEX p1_c1_val3 ON p1_c1 (val); 80 | CREATE INDEX p1_c1_c1_val1 ON p1_c1_c1 (val); 81 | CREATE INDEX p1_c1_c1_val2 ON p1_c1_c1 (val); 82 | CREATE INDEX p1_c1_c1_val3 ON p1_c1_c1 (val); 83 | CREATE INDEX p1_c1_c2_val1 ON p1_c1_c2 (val); 84 | CREATE INDEX p1_c1_c2_val2 ON p1_c1_c2 (val); 85 | CREATE INDEX p1_c1_c2_val3 ON p1_c1_c2 (val); 86 | CREATE INDEX p1_c2_val1 ON p1_c2 (val); 87 | CREATE INDEX p1_c2_val2 ON p1_c2 (val); 88 | CREATE INDEX p1_c2_val3 ON p1_c2 (val); 89 | CREATE INDEX p1_c3_val1 ON p1_c3 (val); 90 | CREATE INDEX p1_c3_val2 ON p1_c3 (val); 91 | CREATE INDEX p1_c3_val3 ON p1_c3 (val); 92 | CREATE INDEX p1_c3_c1_val1 ON p1_c3_c1 (val); 93 | CREATE INDEX p1_c3_c1_val2 ON p1_c3_c1 (val); 94 | CREATE INDEX p1_c3_c1_val3 ON p1_c3_c1 (val); 95 | CREATE INDEX p1_c3_c2_val1 ON p1_c3_c2 (val); 96 | CREATE INDEX p1_c3_c2_val2 ON p1_c3_c2 (val); 97 | CREATE INDEX p1_c3_c2_val3 ON p1_c3_c2 (val); 98 | CREATE INDEX p1_c4_val1 ON p1_c4 (val); 99 | CREATE INDEX p1_c4_val2 ON p1_c4 (val); 100 | CREATE INDEX p1_c4_val3 ON p1_c4 (val); 101 | 102 | ANALYZE t1; 103 | ANALYZE t2; 104 | ANALYZE t3; 105 | ANALYZE t4; 106 | ANALYZE t5; 107 | ANALYZE p1; 108 | ANALYZE p1_c1; 109 | ANALYZE p1_c2; 110 | ANALYZE p2; 111 | 112 | CREATE VIEW v1 AS SELECT id, val FROM t1; 113 | CREATE VIEW v2 AS SELECT t1.id t1_id, t1.val t1_val, t2.id t2_id, t2.val t2_val FROM t1, t2 WHERE t1.id = t2.id; 114 | CREATE VIEW v3 AS SELECT t_1.id t1_id, t_1.val t1_val, t_2.id t2_id, t_2.val t2_val FROM t1 t_1, t2 t_2 WHERE t_1.id = t_2.id; 115 | CREATE VIEW v4 AS SELECT v_2.t1_id, t_3.id FROM v2 v_2, t3 t_3 WHERE v_2.t1_id = t_3.id; 116 | 117 | /* 118 | * Utility function to retrieve a query ID from a query. 119 | * 120 | * This wraps the input query within an EXPLAIN (VERBOSE, FORMAT json) and 121 | * returns its query ID. 122 | */ 123 | CREATE FUNCTION get_query_id(text) RETURNS bigint 124 | LANGUAGE plpgsql AS 125 | $$ 126 | DECLARE 127 | query text; 128 | explain_output text; 129 | query_id bigint; 130 | BEGIN 131 | query = 'EXPLAIN (VERBOSE, FORMAT json) ' || $1; 132 | EXECUTE query INTO explain_output; 133 | SELECT INTO query_id ((explain_output::jsonb)->0->'Query Identifier')::bigint; 134 | return query_id; 135 | END; 136 | $$; 137 | 138 | /* 139 | * The following GUC parameters need the setting of the default value to 140 | * succeed in regression test. 141 | */ 142 | SELECT current_database() AS datname \gset 143 | 144 | /* Fix auto-tunable parameters */ 145 | ALTER DATABASE :"datname" SET effective_cache_size TO 16384; 146 | SET effective_cache_size TO 16384; 147 | 148 | CREATE VIEW settings AS 149 | SELECT name, setting, category 150 | FROM pg_settings 151 | WHERE category LIKE 'Query Tuning%' 152 | OR name = 'client_min_messages' 153 | ORDER BY category, name; 154 | SELECT * FROM settings; 155 | 156 | -- EXPLAIN filtering 157 | -- 158 | -- A lot of tests rely on EXPLAIN being executed with costs enabled 159 | -- to check the validity of the plans generated with hints. 160 | -- 161 | -- This function takes in input a query, executes it and applies some 162 | -- filtering to ensure a stable output. See the tests calling this 163 | -- function to see how it can be used. 164 | -- 165 | -- If required, this can be extended with new operation modes. 166 | CREATE OR REPLACE FUNCTION explain_filter(text) RETURNS SETOF text 167 | LANGUAGE plpgsql AS 168 | $$ 169 | DECLARE 170 | ln text; 171 | BEGIN 172 | FOR ln IN EXECUTE $1 173 | LOOP 174 | -- Replace cost values with some 'xxx' 175 | ln := regexp_replace(ln, 'cost=10{7}[.0-9]+ ', 'cost={inf}..{inf} '); 176 | ln := regexp_replace(ln, 'cost=[.0-9]+ ', 'cost=xxx..xxx '); 177 | -- Replace width with some 'xxx' 178 | ln := regexp_replace(ln, 'width=[0-9]+([^0-9])', 'width=xxx\1'); 179 | -- Filter foreign files 180 | ln := regexp_replace(ln, '^( +Foreign File: ).*$', '\1 (snip..)'); 181 | return next ln; 182 | END LOOP; 183 | END; 184 | $$; 185 | 186 | ANALYZE; 187 | -------------------------------------------------------------------------------- /sql/oldextversions.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- tests for upgrade paths 3 | -- 4 | 5 | CREATE EXTENSION pg_hint_plan VERSION "1.3.0"; 6 | \dx+ pg_hint_plan 7 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.1"; 8 | \dx+ pg_hint_plan 9 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.2"; 10 | \dx+ pg_hint_plan 11 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.3"; 12 | \dx+ pg_hint_plan 13 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.4"; 14 | \dx+ pg_hint_plan 15 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.5"; 16 | \dx+ pg_hint_plan 17 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.6"; 18 | \dx+ pg_hint_plan 19 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.7"; 20 | \dx+ pg_hint_plan 21 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.8"; 22 | \dx+ pg_hint_plan 23 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.9"; 24 | \dx+ pg_hint_plan 25 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.3.10"; 26 | \dx+ pg_hint_plan 27 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4"; 28 | \dx+ pg_hint_plan 29 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.1"; 30 | \dx+ pg_hint_plan 31 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.2"; 32 | \dx+ pg_hint_plan 33 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.4.3"; 34 | \dx+ pg_hint_plan 35 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5"; 36 | \dx+ pg_hint_plan 37 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5.1"; 38 | \dx+ pg_hint_plan 39 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.5.2"; 40 | \dx+ pg_hint_plan 41 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.6.0"; 42 | \dx+ pg_hint_plan 43 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.6.1"; 44 | \dx+ pg_hint_plan 45 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.7.0"; 46 | \dx+ pg_hint_plan 47 | \d hint_plan.hints 48 | ALTER EXTENSION pg_hint_plan UPDATE TO "1.8.0"; 49 | \dx+ pg_hint_plan 50 | DROP EXTENSION pg_hint_plan; 51 | -------------------------------------------------------------------------------- /sql/plpgsql.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Scenarios with various PL/pgsql functions 3 | -- 4 | 5 | SET search_path TO public; 6 | SET client_min_messages TO log; 7 | \set SHOW_CONTEXT always 8 | 9 | LOAD 'pg_hint_plan'; 10 | SET pg_hint_plan.debug_print TO on; 11 | SET compute_query_id = on; 12 | SHOW pg_hint_plan.enable_hint_table; 13 | 14 | -- Internal handling of hints within plpgsql functions. 15 | -- This forces an exception, manipulating internally plpgsql_recurse_level. 16 | create or replace function test_hint_exception(level int) 17 | returns void language plpgsql as $$ 18 | begin 19 | level := level + 1; 20 | raise notice 'Execution of test_hint_exception at level %', level; 21 | if level > 1 then 22 | -- This triggers the exception below, ending execution. 23 | execute 'select ''x''::numeric'; 24 | end if; 25 | raise notice 'End of test_hint_exception at level %', level; 26 | execute 'select test_hint_exception(' || level || ')'; 27 | exception when others then end; 28 | $$; 29 | -- Having a transaction context is essential to mess up with the 30 | -- plpgsql_recurse_level. 31 | begin; 32 | select set_config('compute_query_id','off', true); 33 | -- Show plan without hints 34 | explain (costs false) with test as (select 'z' val) 35 | select t1.val from test t1, test t2 where t1.val = t2.val; 36 | -- Invoke function that internally throws an exception with two 37 | -- levels of nesting. 38 | select test_hint_exception(0); 39 | -- Show plan with hint, stored as an internal state of plpgsql_recurse_level. 40 | explain (costs false) with test /*+ MergeJoin(t1 t2) */ 41 | as (select 'x' val) select t1.val from test t1, test t2 where t1.val = t2.val; 42 | -- This query should have the same plan as the first one, without hints. 43 | explain (costs false) with test as (select 'y' val) 44 | select t1.val from test t1, test t2 where t1.val = t2.val; 45 | -- Again, with one level of nesting. 46 | select test_hint_exception(1); 47 | -- Show plan with hint. 48 | explain (costs false) with test /*+ MergeJoin(t1 t2) */ 49 | as (select 'x' val) select t1.val from test t1, test t2 where t1.val = t2.val; 50 | -- This query should have no hints. 51 | explain (costs false) with test as (select 'y' val) 52 | select t1.val from test t1, test t2 where t1.val = t2.val; 53 | rollback; 54 | -- Still no hints used here. 55 | explain (costs false) with test as (select 'y' val) 56 | select t1.val from test t1, test t2 where t1.val = t2.val; 57 | drop function test_hint_exception; 58 | 59 | -- Test hints with function using transactions internally. 60 | create table test_hint_tab (a int); 61 | -- Function called in a nested loop to check for hints. 62 | create function test_hint_queries(run int, level int) returns void 63 | language plpgsql as $$ 64 | declare c text; 65 | begin 66 | level := level + 1; 67 | -- Stopping at two levels of nesting should be sufficient.. 68 | if level > 2 then 69 | return; 70 | end if; 71 | -- Mix of queries with and without hints. The level is mixed in the 72 | -- query string to show it in the output generated. 73 | raise notice 'Execution % at level %, hash-join t2/t1 hint', run, level; 74 | execute 'explain (costs false) with test /*+ HashJoin(t2 t1) */ 75 | as (select ' || level || ' val) 76 | select t1.val from test t1, test t2 where t1.val = t2.val;' 77 | into c; 78 | raise notice 'Execution % at level %, no hints', run, level; 79 | execute 'explain (costs false) with test 80 | as (select ' || level || ' val) 81 | select t1.val from test t1, test t2 where t1.val = t2.val;' 82 | into c; 83 | raise notice 'Execution % at level %, merge-join t1/t2 hint', run, level; 84 | execute 'explain (costs false) with test /*+ MergeJoin(t1 t2) */ 85 | as (select ' || level || ' val) 86 | select t1.val from test t1, test t2 where t1.val = t2.val;' 87 | into c; 88 | execute 'select test_hint_queries(' || run || ',' || level || ')'; 89 | end; $$; 90 | 91 | -- Entry point of this test. This executes the transaction 92 | -- commands while calling test_hint_queries in a nested loop. 93 | -- "mode" can be set to "before" or "after", to control the timing of 94 | -- the subtransaction commands launched in this procedure. 95 | create procedure test_hint_transaction(mode text) 96 | language plpgsql as $$ 97 | declare c text; 98 | begin 99 | for i in 0..3 loop 100 | 101 | if mode = 'before' then 102 | execute 'select test_hint_queries(' || i || ', 0)'; 103 | insert into test_hint_tab (a) values (i); 104 | end if; 105 | 106 | -- Mix commits and rollbacks. 107 | if i % 2 = 0 then 108 | commit; 109 | else 110 | rollback; 111 | end if; 112 | 113 | if mode = 'after' then 114 | execute 'select test_hint_queries(' || i || ', 0)'; 115 | insert into test_hint_tab (a) values (i); 116 | end if; 117 | end loop; 118 | end; $$; 119 | 120 | call test_hint_transaction('before'); 121 | call test_hint_transaction('after'); 122 | 123 | table test_hint_tab; 124 | drop procedure test_hint_transaction; 125 | drop function test_hint_queries; 126 | drop table test_hint_tab; 127 | -------------------------------------------------------------------------------- /sql/ut-G.sql: -------------------------------------------------------------------------------- 1 | LOAD 'pg_hint_plan'; 2 | SET pg_hint_plan.enable_hint TO on; 3 | SET pg_hint_plan.debug_print TO on; 4 | SET client_min_messages TO LOG; 5 | SET search_path TO public; 6 | 7 | ---- 8 | ---- No. G-1-1 RULE definition table 9 | ---- 10 | 11 | -- No. G-1-1-1 12 | EXPLAIN (COSTS false) UPDATE s1.r1 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 13 | /*+ 14 | Set(enable_tidscan off)Set(enable_nestloop off) 15 | */ 16 | EXPLAIN (COSTS false) UPDATE s1.r1 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 17 | EXPLAIN (COSTS false) UPDATE s1.r1_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 18 | /*+ 19 | Set(enable_tidscan off)Set(enable_nestloop off) 20 | */ 21 | EXPLAIN (COSTS false) UPDATE s1.r1_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 22 | 23 | -- No. G-1-1-2 24 | EXPLAIN (COSTS false) UPDATE s1.r2 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 25 | /*+ 26 | Set(enable_tidscan off)Set(enable_nestloop off) 27 | */ 28 | EXPLAIN (COSTS false) UPDATE s1.r2 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 29 | EXPLAIN (COSTS false) UPDATE s1.r2_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 30 | /*+ 31 | Set(enable_tidscan off)Set(enable_nestloop off) 32 | */ 33 | EXPLAIN (COSTS false) UPDATE s1.r2_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 34 | 35 | -- No. G-1-1-3 36 | EXPLAIN (COSTS false) UPDATE s1.r3 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 37 | /*+ 38 | Set(enable_tidscan off)Set(enable_nestloop off) 39 | */ 40 | EXPLAIN (COSTS false) UPDATE s1.r3 SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 41 | EXPLAIN (COSTS false) UPDATE s1.r3_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 42 | /*+ 43 | Set(enable_tidscan off)Set(enable_nestloop off) 44 | */ 45 | EXPLAIN (COSTS false) UPDATE s1.r3_ SET c1 = c1 WHERE c1 = 1 AND ctid = '(1,1)'; 46 | 47 | ---- 48 | ---- No. G-2-1 GUC parameter 49 | ---- 50 | 51 | -- No. G-2-1-3 52 | /*+Set(1234567890123456789012345678901234567890123456789012345678901234 1)*/ 53 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 54 | 55 | -- No. G-2-1-4 56 | /*+Set(constraint_exclusion 1234567890123456789012345678901234567890123456789012345678901234)*/ 57 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 58 | 59 | ---- 60 | ---- No. G-2-2 category of GUC parameter and role 61 | ---- 62 | 63 | -- No. G-2-2-1 64 | SET ROLE regress_super_user; 65 | /*+Set(block_size 16384)*/ 66 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 67 | 68 | -- No. G-2-2-2 69 | /*+Set(archive_mode off)*/ 70 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 71 | 72 | -- No. G-2-2-3 73 | /*+Set(archive_timeout 0)*/ 74 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 75 | 76 | -- No. G-2-2-4 77 | /*+Set(log_connections off)*/ 78 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 79 | 80 | -- No. G-2-2-5 81 | /*+Set(log_min_messages WARNING)*/ 82 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 83 | RESET ROLE; 84 | 85 | -- No. G-2-2-6 86 | GRANT ALL ON SCHEMA s1 TO PUBLIC; 87 | GRANT SELECT ON ALL TABLES IN SCHEMA s1 TO regress_normal_user; 88 | SET ROLE regress_normal_user; 89 | /*+Set(log_min_messages WARNING)*/ 90 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 91 | 92 | -- No. G-2-2-7 93 | /*+Set(enable_seqscan on)*/ 94 | SELECT * FROM s1.t1 WHERE t1.c1 = 1; 95 | 96 | RESET ROLE; 97 | REVOKE SELECT ON ALL TABLES IN SCHEMA s1 FROM regress_normal_user; 98 | REVOKE ALL ON SCHEMA s1 FROM PUBLIC; 99 | 100 | ---- 101 | ---- No. G-2-3 conflict set hint 102 | ---- 103 | 104 | SET client_min_messages TO LOG; 105 | -- No. G-2-3-1 106 | /*+Set(enable_indexscan on)Set(enable_indexscan off)*/ 107 | SELECT * FROM s1.t1 WHERE false; 108 | 109 | -- No. G-2-3-2 110 | /*+Set(client_min_messages DEBUG5)Set(client_min_messages WARNING)Set(client_min_messages DEBUG2)*/ 111 | SELECT * FROM s1.t1 WHERE false; 112 | 113 | -- No. G-2-3-3 114 | /*+Set(enable_indexscan on)Set(enable_indexscan o)*/ 115 | SELECT * FROM s1.t1 WHERE false; 116 | 117 | -- No. G-2-3-4 118 | /*+Set(client_min_messages DEBUG5)Set(client_min_messages WARNING)Set(client_min_messages DEBU)*/ 119 | SELECT * FROM s1.t1 WHERE false; 120 | 121 | ---- 122 | ---- No. G-2-4 debug message 123 | ---- 124 | 125 | -- No. G-2-4-1 126 | /*+SeqScan(a)IndexScan(a)SeqScan(c)NestLoop(a) */ 127 | SELECT * FROM s1.t1 a, s1.t2 b WHERE false; 128 | -------------------------------------------------------------------------------- /sql/ut-T.sql: -------------------------------------------------------------------------------- 1 | -- ut-T: tests for table hints 2 | -- This test is focusing on hint retrieval from table 3 | 4 | LOAD 'pg_hint_plan'; 5 | SET pg_hint_plan.enable_hint TO on; 6 | SET pg_hint_plan.debug_print TO on; 7 | SET client_min_messages TO LOG; 8 | SET search_path TO public; 9 | 10 | -- This hint affects queries with an equivalent query ID when executed as 11 | -- a subquery. 12 | SET pg_hint_plan.enable_hint_table TO on; 13 | SELECT get_query_id('SELECT * FROM t1 WHERE id = 1;') AS query_id \gset 14 | INSERT INTO hint_plan.hints VALUES (DEFAULT, :'query_id', '', 'SeqScan(t1)'); 15 | 16 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 17 | 18 | -- These queries uses IndexScan without hints 19 | SET pg_hint_plan.enable_hint_table to off; 20 | EXPLAIN (COSTS false) SELECT * FROM t1 WHERE id = 100; 21 | EXPLAIN (COSTS false) EXECUTE p1; 22 | DEALLOCATE p1; 23 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 24 | EXPLAIN (COSTS false) CREATE TABLE ct1 AS EXECUTE p1; 25 | 26 | DEALLOCATE p1; 27 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 28 | 29 | -- Forced to use SeqScan by table hints 30 | SET pg_hint_plan.enable_hint_table to on; 31 | EXPLAIN (COSTS false) SELECT * FROM t1 WHERE id = 100; 32 | EXPLAIN (COSTS false) EXECUTE p1; 33 | DEALLOCATE p1; 34 | PREPARE p1 AS SELECT * FROM t1 WHERE id = 100; 35 | EXPLAIN (COSTS false) CREATE TABLE ct1 AS EXECUTE p1; 36 | 37 | DEALLOCATE p1; 38 | 39 | SET pg_hint_plan.enable_hint_table to off; 40 | DELETE FROM hint_plan.hints; 41 | 42 | -------------------------------------------------------------------------------- /sql/ut-W.sql: -------------------------------------------------------------------------------- 1 | LOAD 'pg_hint_plan'; 2 | SET pg_hint_plan.enable_hint TO on; 3 | SET pg_hint_plan.debug_print TO on; 4 | SET client_min_messages TO LOG; 5 | 6 | -- Queries on ordinary tables with default setting 7 | EXPLAIN (COSTS false) SELECT * FROM s1.t1; 8 | -- Note that parallel is not enforced on a single relation without 9 | -- the GUCs related to parallelism reset. 10 | /*+Parallel(t1 5 hard)*/ 11 | EXPLAIN (COSTS false) SELECT * FROM s1.t1; 12 | -- Still it works for multiple relations. 13 | /*+Parallel(t11 5 hard)*/ 14 | EXPLAIN (COSTS false) SELECT * FROM s1.t1 as t11, s1.t1 as t12; 15 | 16 | SET parallel_setup_cost to 0; 17 | SET parallel_tuple_cost to 0; 18 | SET min_parallel_table_scan_size to 0; 19 | SET min_parallel_index_scan_size to 0; 20 | SET max_parallel_workers_per_gather to DEFAULT; 21 | 22 | /*+Parallel(t1 8)*/ 23 | EXPLAIN (COSTS false) SELECT * FROM s1.t1; 24 | 25 | /*+Parallel(t1 8 soft)*/ 26 | EXPLAIN (COSTS false) SELECT * FROM s1.t1; 27 | 28 | /*+Parallel(t1 8 hard)*/ 29 | EXPLAIN (COSTS false) SELECT * FROM s1.t1; 30 | 31 | /*+Parallel(t1 4 hard) */ /* to be gather merge*/ 32 | EXPLAIN (COSTS false) SELECT * FROM s1.t1 ORDER BY s1.t1.c1 LIMIT 4; 33 | 34 | -- Queries on inheritance tables 35 | SET parallel_setup_cost to 0; 36 | SET parallel_tuple_cost to 0; 37 | SET min_parallel_table_scan_size to 0; 38 | SET min_parallel_index_scan_size to 0; 39 | SET enable_parallel_append to false; 40 | /*+Parallel(p1 8)*/ 41 | EXPLAIN (COSTS false) SELECT * FROM p1; 42 | SET enable_parallel_append to true; 43 | /*+Parallel(p1 8)*/ 44 | EXPLAIN (COSTS false) SELECT * FROM p1; 45 | 46 | SET parallel_setup_cost to DEFAULT; 47 | SET parallel_tuple_cost to DEFAULT; 48 | SET min_parallel_table_scan_size to DEFAULT; 49 | SET min_parallel_index_scan_size to DEFAULT; 50 | 51 | SET enable_parallel_append to false; 52 | /*+Parallel(p1 8 hard)*/ 53 | EXPLAIN (COSTS false) SELECT * FROM p1; 54 | 55 | SET enable_parallel_append to true; 56 | /*+Parallel(p1 8 hard)*/ 57 | EXPLAIN (COSTS false) SELECT * FROM p1; 58 | 59 | -- hinting on children doesn't work (changed as of pg_hint_plan 10) 60 | SET enable_parallel_append to false; 61 | /*+Parallel(p1_c1 8 hard)*/ 62 | EXPLAIN (COSTS false) SELECT * FROM p1; 63 | SET enable_parallel_append to true; 64 | /*+Parallel(p1_c1 8 hard)*/ 65 | EXPLAIN (COSTS false) SELECT * FROM p1; 66 | 67 | 68 | -- Joins 69 | EXPLAIN (COSTS false) SELECT * FROM p1_c1_c1 join p2_c1_c1 on p1_c1_c1.id = p2_c1_c1.id; 70 | 71 | /*+Parallel(p1_c1_c1 8 hard)*/ 72 | EXPLAIN (COSTS false) SELECT * FROM p1_c1_c1 join p2_c1_c1 on p1_c1_c1.id = p2_c1_c1.id; 73 | 74 | SET parallel_setup_cost to 0; 75 | SET parallel_tuple_cost to 0; 76 | SET min_parallel_table_scan_size to 0; 77 | SET min_parallel_index_scan_size to 0; 78 | 79 | /*+Parallel(p1_c1_c1 8 soft) Parallel(p2_c1_c1 0)*/ 80 | EXPLAIN (COSTS false) SELECT * FROM p1_c1_c1 join p2_c1_c1 on p1_c1_c1.id = p2_c1_c1.id; 81 | 82 | /*+Parallel(p1_c1_c1 8 hard) Parallel(p2_c1_c1 0)*/ 83 | EXPLAIN (COSTS false) SELECT * FROM p1_c1_c1 join p2_c1_c1 on p1_c1_c1.id = p2_c1_c1.id; 84 | 85 | /*+Parallel(p1_c1_c1 8 hard) Parallel(p2_c1_c1 8 hard)*/ 86 | EXPLAIN (COSTS false) SELECT * FROM p1_c1_c1 join p2_c1_c1 on p1_c1_c1.id = p2_c1_c1.id; 87 | 88 | 89 | -- Joins on inheritance tables 90 | SET parallel_setup_cost to 0; 91 | SET parallel_tuple_cost to 0; 92 | SET min_parallel_table_scan_size to 0; 93 | SET min_parallel_index_scan_size to 0; 94 | SET enable_parallel_append to false; 95 | /*+Parallel(p1 8)*/ 96 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 97 | SET enable_parallel_append to true; 98 | /*+Parallel(p1 8)*/ 99 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 100 | 101 | SET enable_parallel_append to false; 102 | /*+Parallel(p1 8)Parallel(p2 0)*/ 103 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 104 | SET enable_parallel_append to true; 105 | /*+Parallel(p1 8)Parallel(p2 0)*/ 106 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 107 | 108 | SET parallel_setup_cost to DEFAULT; 109 | SET parallel_tuple_cost to DEFAULT; 110 | SET min_parallel_table_scan_size to DEFAULT; 111 | SET min_parallel_index_scan_size to DEFAULT; 112 | 113 | /*+Parallel(p2 8 soft)*/ 114 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 115 | 116 | /*+Parallel(p2 8 hard)*/ 117 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 118 | 119 | -- Number of workers results to the largest number 120 | SET enable_parallel_append to false; 121 | /*+Parallel(p2 8 hard) Parallel(p1 5 hard) */ 122 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 123 | SET enable_parallel_append to true; 124 | /*+Parallel(p2 8 hard) Parallel(p1 5 hard) */ 125 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 126 | 127 | 128 | -- Mixture with scan hints 129 | -- p1 can be parallel 130 | SET enable_parallel_append to false; 131 | /*+Parallel(p1 8 hard) IndexScan(p2) */ 132 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 133 | SET enable_parallel_append to true; 134 | /*+Parallel(p1 8 hard) IndexScan(p2) */ 135 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 136 | 137 | -- Parallel sequential scan 138 | SET enable_parallel_append to false; 139 | /*+Parallel(p1 8 hard) SeqScan(p1) */ 140 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 141 | SET enable_parallel_append to true; 142 | /*+Parallel(p1 8 hard) SeqScan(p1) */ 143 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 144 | 145 | -- Parallel index scan 146 | SET enable_parallel_append to false; 147 | /*+Parallel(p1 8 hard) IndexScan(p1) */ 148 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 149 | SET enable_parallel_append to true; 150 | /*+Parallel(p1 8 hard) IndexScan(p1) */ 151 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 152 | 153 | -- This hint doesn't turn on parallel, so the Parallel hint is ignored 154 | set max_parallel_workers_per_gather TO 0; 155 | /*+Parallel(p1 0 hard) IndexScan(p1) */ 156 | EXPLAIN (COSTS false) SELECT * FROM p1 join p2 on p1.id = p2.id; 157 | 158 | 159 | -- Parallel on UNION 160 | EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; 161 | 162 | -- parallel hinting on any relation enables parallel 163 | SET parallel_setup_cost to 0; 164 | SET parallel_tuple_cost to 0; 165 | SET min_parallel_table_scan_size to 0; 166 | SET min_parallel_index_scan_size to 0; 167 | SET max_parallel_workers_per_gather to 0; 168 | 169 | /*+Parallel(p1 8) */ 170 | EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; 171 | 172 | -- set hint has the same effect 173 | /*+Set(max_parallel_workers_per_gather 1)*/ 174 | EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; 175 | 176 | -- applies largest number of workers on merged parallel paths 177 | SET parallel_setup_cost to DEFAULT; 178 | SET parallel_tuple_cost to DEFAULT; 179 | SET min_parallel_table_scan_size to DEFAULT; 180 | SET min_parallel_index_scan_size to DEFAULT; 181 | SET max_parallel_workers_per_gather to 8; 182 | /*+Parallel(p1 5 hard)Parallel(p2 6 hard) */ 183 | EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; 184 | 185 | -- On empty tables, parallel hints can only be enforced for index scans 186 | -- and not sequential scans. Adding a single row allows a parallel 187 | -- hint to be enforced on a sequential scan. It is a bit weird that 188 | -- having no rows controls how parallel workers are triggered, but 189 | -- at the same time we have nothing to query, and this is an old 190 | -- historical (and accidental) behavior. 191 | /*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ 192 | EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; 193 | /*+Parallel(t5 4 hard) Parallel(t6 2 hard) NoSeqScan(t5) NoSeqScan(t6) */ 194 | EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; 195 | INSERT INTO s1.t5 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; 196 | INSERT INTO s1.t6 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; 197 | ANALYZE s1.t5; 198 | ANALYZE s1.t6; 199 | /*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ 200 | EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; 201 | 202 | -- Negative hints 203 | SET enable_indexscan to DEFAULT; 204 | SET parallel_setup_cost to 0; 205 | SET parallel_tuple_cost to 0; 206 | SET min_parallel_table_scan_size to 0; 207 | SET min_parallel_index_scan_size to 0; 208 | SET max_parallel_workers_per_gather to 5; 209 | EXPLAIN (COSTS false) SELECT * FROM p1; 210 | 211 | SET enable_parallel_append to false; 212 | /*+Parallel(p1 0 hard)*/ 213 | EXPLAIN (COSTS false) SELECT * FROM p1; 214 | SET enable_parallel_append to true; 215 | /*+Parallel(p1 0 hard)*/ 216 | EXPLAIN (COSTS false) SELECT * FROM p1; 217 | 218 | -- Errors 219 | /*+Parallel(p1 100x hard)Parallel(p1 -1000 hard)Parallel(p1 1000000 hard) 220 | Parallel(p1 8 hoge)Parallel(p1)Parallel(p1 100 soft x)*/ 221 | EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; 222 | 223 | -- Hints on unhintable relations are just ignored 224 | SELECT explain_filter(' 225 | /*+Parallel(p1 5 hard) Parallel(s1 3 hard) IndexScan(ft1) SeqScan(cte1) 226 | IndexScan(t) IndexScan(*VALUES*) */ 227 | EXPLAIN (COSTS false) SELECT id FROM p1_c1_c1 as s1 TABLESAMPLE SYSTEM(10) 228 | UNION ALL 229 | SELECT id FROM ft1 230 | UNION ALL 231 | (WITH cte1 AS (SELECT id FROM p1 WHERE id % 2 = 0) SELECT id FROM cte1) 232 | UNION ALL 233 | SELECT x FROM (VALUES (1), (2), (3)) t(x); 234 | '); 235 | -------------------------------------------------------------------------------- /sql/ut-fdw.sql: -------------------------------------------------------------------------------- 1 | -- directory paths and dlsuffix are passed to us in environment variables 2 | \getenv abs_srcdir PG_ABS_SRCDIR 3 | \set filename :abs_srcdir '/data/data.csv' 4 | 5 | LOAD 'pg_hint_plan'; 6 | SET search_path TO public; 7 | SET pg_hint_plan.debug_print TO on; 8 | SET client_min_messages TO LOG; 9 | SET pg_hint_plan.enable_hint TO on; 10 | 11 | CREATE EXTENSION file_fdw; 12 | CREATE SERVER file_server FOREIGN DATA WRAPPER file_fdw; 13 | CREATE USER MAPPING FOR PUBLIC SERVER file_server; 14 | CREATE FOREIGN TABLE ft1 (id int, val int) SERVER file_server OPTIONS (format 'csv', filename :'filename'); 15 | 16 | -- foreign table test 17 | SELECT * FROM ft1; 18 | \t 19 | SELECT explain_filter(' 20 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 21 | '); 22 | 23 | ---- 24 | ---- No. S-1-5 object type for the hint 25 | ---- 26 | 27 | -- No. S-1-5-6 28 | SELECT explain_filter(' 29 | /*+SeqScan(t1)SeqScan(ft_1)SeqScan(ft_2)*/ 30 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 31 | '); 32 | 33 | ---- 34 | ---- No. J-1-6 object type for the hint 35 | ---- 36 | 37 | -- No. J-1-6-6 38 | SELECT explain_filter(' 39 | /*+MergeJoin(ft_1 ft_2)Leading(ft_1 ft_2 t1)*/ 40 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 41 | '); 42 | 43 | ---- 44 | ---- No. L-1-6 object type for the hint 45 | ---- 46 | 47 | -- No. L-1-6-6 48 | SELECT explain_filter(' 49 | /*+Leading(ft_1 ft_2 t1)*/ 50 | EXPLAIN (COSTS false) SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 51 | '); 52 | 53 | ---- 54 | ---- No. R-1-6 object type for the hint 55 | ---- 56 | 57 | -- No. R-1-6-6 58 | SELECT explain_filter(' 59 | /*+Rows(ft_1 ft_2 #1)Leading(ft_1 ft_2 t1)*/ 60 | EXPLAIN SELECT * FROM s1.t1, ft1 ft_1, ft1 ft_2 WHERE t1.c1 = ft_1.id AND t1.c1 = ft_2.id; 61 | '); 62 | -------------------------------------------------------------------------------- /sql/ut-fini.sql: -------------------------------------------------------------------------------- 1 | DROP ROLE IF EXISTS regress_super_user; 2 | DROP ROLE IF EXISTS regress_normal_user; 3 | DROP EXTENSION pg_hint_plan; 4 | -------------------------------------------------------------------------------- /sql/ut-init.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO public; 2 | 3 | CREATE EXTENSION btree_gist; 4 | CREATE EXTENSION btree_gin; 5 | 6 | CREATE ROLE regress_super_user 7 | SUPERUSER 8 | NOCREATEDB 9 | NOCREATEROLE 10 | NOINHERIT 11 | NOLOGIN 12 | NOREPLICATION 13 | CONNECTION LIMIT 1; 14 | CREATE ROLE regress_normal_user 15 | NOSUPERUSER 16 | NOCREATEDB 17 | NOCREATEROLE 18 | NOINHERIT 19 | NOLOGIN 20 | NOREPLICATION 21 | CONNECTION LIMIT 1; 22 | 23 | CREATE SCHEMA s1; 24 | CREATE SCHEMA s2; 25 | 26 | CREATE TABLE s1.t1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1)); 27 | CREATE TABLE s1.t2 (LIKE s1.t1 INCLUDING ALL); 28 | CREATE TABLE s1.t3 (LIKE s1.t1 INCLUDING ALL); 29 | CREATE TABLE s1.t4 (LIKE s1.t1 INCLUDING ALL); 30 | CREATE TABLE s1.t5 (LIKE s1.t1 INCLUDING ALL); 31 | CREATE TABLE s1.t6 (LIKE s1.t1 INCLUDING ALL); 32 | CREATE TABLE s2.t1 (LIKE s1.t1 INCLUDING ALL); 33 | CREATE TABLE s1.p1 (LIKE s1.t1 INCLUDING ALL); 34 | CREATE UNIQUE INDEX p1_parent ON s1.p1 USING btree (c4 COLLATE "C" varchar_ops ASC NULLS LAST, (c1 * 2 < 100)) WHERE c1 < 10; 35 | CREATE TABLE s1.p2 (LIKE s1.t1 INCLUDING ALL); 36 | CREATE TABLE s1.p1c1 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 <= 100)) INHERITS(s1.p1); 37 | CREATE TABLE s1.p1c2 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 200)) INHERITS(s1.p1); 38 | CREATE TABLE s1.p1c3 (LIKE s1.p1 INCLUDING ALL, CHECK (c1 > 200)) INHERITS(s1.p1); 39 | CREATE TABLE s1.p2c1 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 <= 100)) INHERITS(s1.p2); 40 | CREATE TABLE s1.p2c2 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 200)) INHERITS(s1.p2); 41 | CREATE TABLE s1.p2c3 (LIKE s1.p2 INCLUDING ALL, CHECK (c1 > 200)) INHERITS(s1.p2); 42 | CREATE TABLE s1.p2c1c1 (LIKE s1.p2c1 INCLUDING ALL, CHECK (c1 <= 50)) INHERITS(s1.p2c1); 43 | CREATE TABLE s1.p2c1c2 (LIKE s1.p2c1 INCLUDING ALL, CHECK (c1 > 50 AND c1 <= 100)) INHERITS(s1.p2c1); 44 | CREATE TABLE s1.p2c2c1 (LIKE s1.p2c2 INCLUDING ALL, CHECK (c1 > 100 AND c1 <= 150)) INHERITS(s1.p2c2); 45 | CREATE TABLE s1.p2c2c2 (LIKE s1.p2c2 INCLUDING ALL, CHECK (c1 > 150 AND c1 <= 200)) INHERITS(s1.p2c2); 46 | CREATE TABLE s1.p2c3c1 (LIKE s1.p2c3 INCLUDING ALL, CHECK (c1 > 200 AND c1 <= 250)) INHERITS(s1.p2c3); 47 | CREATE TABLE s1.p2c3c2 (LIKE s1.p2c3 INCLUDING ALL, CHECK (c1 > 250)) INHERITS(s1.p2c3); 48 | 49 | CREATE TABLE s1.r1 (LIKE s1.t1); 50 | CREATE TABLE s1.r2 (LIKE s1.t1); 51 | CREATE TABLE s1.r3 (LIKE s1.t1); 52 | CREATE TABLE s1.r4 (LIKE s1.t1); 53 | CREATE TABLE s1.r5 (LIKE s1.t1); 54 | CREATE TABLE s1.r1_ (LIKE s1.t1); 55 | CREATE TABLE s1.r2_ (LIKE s1.t1); 56 | CREATE TABLE s1.r3_ (LIKE s1.t1); 57 | CREATE TABLE s1.ti1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1), UNIQUE (c2)); 58 | CREATE TABLE s1.pt1 (c1 int, c2 int, c3 int, c4 int) PARTITION BY RANGE (c1); 59 | CREATE TABLE s1.pt1_c1 PARTITION OF s1.pt1 FOR VALUES FROM (MINVALUE) TO (101); 60 | CREATE TABLE s1.pt1_c2 PARTITION OF s1.pt1 FOR VALUES FROM (101) TO (201); 61 | CREATE TABLE s1.pt1_c3 PARTITION OF s1.pt1 FOR VALUES FROM (201) TO (MAXVALUE); 62 | CREATE UNLOGGED TABLE s1.ul1 (LIKE s1.t1 INCLUDING ALL); 63 | 64 | INSERT INTO s1.t1 SELECT i, i, i % 100, i FROM (SELECT generate_series(1, 1000) i) t; 65 | INSERT INTO s1.t2 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 66 | INSERT INTO s2.t1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 67 | INSERT INTO s1.p1c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 100) i) t; 68 | INSERT INTO s1.p1c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(101, 200) i) t; 69 | INSERT INTO s1.p1c3 SELECT i, i, i % 10, i FROM (SELECT generate_series(201, 300) i) t; 70 | INSERT INTO s1.p2c1c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 50) i) t; 71 | INSERT INTO s1.p2c1c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(51, 100) i) t; 72 | INSERT INTO s1.p2c2c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(101, 150) i) t; 73 | INSERT INTO s1.p2c2c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(151, 200) i) t; 74 | INSERT INTO s1.p2c3c1 SELECT i, i, i % 10, i FROM (SELECT generate_series(201, 250) i) t; 75 | INSERT INTO s1.p2c3c2 SELECT i, i, i % 10, i FROM (SELECT generate_series(251, 300) i) t; 76 | INSERT INTO s1.ti1 SELECT i, i, i % 100, i FROM (SELECT generate_series(1, 1000) i) t; 77 | INSERT INTO s1.pt1 SELECT i, i, i % 10, i FROM (SELECT generate_series(0, 300) i) t; 78 | 79 | CREATE INDEX t1_i ON s1.t1 (c3); 80 | CREATE INDEX t1_i1 ON s1.t1 (c1); 81 | CREATE INDEX t2_i1 ON s1.t2 (c1); 82 | CREATE INDEX t3_i1 ON s1.t3 (c1); 83 | CREATE INDEX t4_i1 ON s1.t4 (c1); 84 | CREATE INDEX p1_i ON s1.p1 (c1); 85 | CREATE INDEX p2_i ON s1.p2 (c1); 86 | CREATE INDEX p1_i2 ON s1.p1 (c2); 87 | CREATE INDEX p1c1_i ON s1.p1c1 (c1); 88 | CREATE INDEX p1c2_i ON s1.p1c2 (c1); 89 | CREATE INDEX p1c3_i ON s1.p1c3 (c1); 90 | CREATE INDEX p2c1_i ON s1.p2c1 (c1); 91 | CREATE INDEX p2c2_i ON s1.p2c2 (c1); 92 | CREATE INDEX p2c3_i ON s1.p2c3 (c1); 93 | CREATE INDEX p2c1c1_i ON s1.p2c1c1 (c1); 94 | CREATE INDEX p2c1c2_i ON s1.p2c1c2 (c1); 95 | CREATE INDEX p2c2c1_i ON s1.p2c2c1 (c1); 96 | CREATE INDEX p2c2c2_i ON s1.p2c2c2 (c1); 97 | CREATE INDEX p2c3c1_i ON s1.p2c3c1 (c1); 98 | CREATE INDEX p2c3c2_i ON s1.p2c3c2 (c1); 99 | CREATE INDEX ti1_i1 ON s1.ti1 (c2); 100 | CREATE INDEX ti1_i2 ON s1.ti1 (c2, c4); 101 | CREATE INDEX ti1_i3 ON s1.ti1 (c2, c4, c4); 102 | CREATE INDEX ti1_i4 ON s1.ti1 (c2, c4, c4, c4); 103 | CREATE INDEX ti1_btree ON s1.ti1 USING btree (c1); 104 | CREATE INDEX ti1_hash ON s1.ti1 USING hash (c1); 105 | CREATE INDEX ti1_gist ON s1.ti1 USING gist (c1); 106 | CREATE INDEX ti1_gin ON s1.ti1 USING gin (c1); 107 | CREATE INDEX ti1_expr ON s1.ti1 ((c1 < 100)); 108 | CREATE INDEX ti1_pred ON s1.ti1 (lower(c4)); 109 | CREATE UNIQUE INDEX ti1_uniq ON s1.ti1 (c1); 110 | CREATE INDEX ti1_multi ON s1.ti1 (c1, c2, c3, c4); 111 | CREATE INDEX ti1_ts ON s1.ti1 USING gin(to_tsvector('english', c4)); 112 | CREATE INDEX pt1_c1_c2_i ON s1.pt1_c1(c2); 113 | CREATE INDEX pt1_c1_c3_i ON s1.pt1_c1(c3); 114 | CREATE INDEX pt1_c2_c2_i ON s1.pt1_c2(c2); 115 | CREATE INDEX pt1_c2_c3_i ON s1.pt1_c2(c3); 116 | CREATE INDEX pt1_c3_c2_i ON s1.pt1_c3(c2); 117 | CREATE INDEX pt1_c3_c3_i ON s1.pt1_c3(c3); 118 | 119 | CREATE VIEW s1.v1 AS SELECT v1t1.c1, v1t1.c2, v1t1.c3, v1t1.c4 FROM s1.t1 v1t1; 120 | CREATE VIEW s1.v1_ AS SELECT v1t1_.c1, v1t1_.c2, v1t1_.c3, v1t1_.c4 FROM s1.t1 v1t1_; 121 | CREATE VIEW s1.v2 AS SELECT v2t1.c1, v2t1.c2, v2t1.c3, v2t1.c4 FROM s1.t1 v2t1 JOIN s1.t2 v2t2 ON(v2t1.c1 = v2t2.c1); 122 | CREATE VIEW s1.v3 AS SELECT v3t1.c1, v3t1.c2, v3t1.c3, v3t1.c4 FROM s1.t1 v3t1 JOIN s1.t2 v3t2 ON(v3t1.c1 = v3t2.c1) JOIN s1.t3 v3t3 ON(v3t1.c1 = v3t3.c1); 123 | 124 | ANALYZE s1.t1; 125 | ANALYZE s1.t2; 126 | ANALYZE s2.t1; 127 | ANALYZE s1.p1; 128 | ANALYZE s1.p2; 129 | ANALYZE s1.p1c1; 130 | ANALYZE s1.p1c2; 131 | ANALYZE s1.p1c3; 132 | ANALYZE s1.p2c1c1; 133 | ANALYZE s1.p2c1c2; 134 | ANALYZE s1.p2c2c1; 135 | ANALYZE s1.p2c2c2; 136 | ANALYZE s1.p2c3c1; 137 | ANALYZE s1.p2c3c2; 138 | ANALYZE s1.ti1; 139 | ANALYZE s1.pt1; 140 | ANALYZE s1.t5; 141 | ANALYZE s1.t6; 142 | 143 | CREATE FUNCTION s1.f1 () RETURNS s1.t1 AS $$ 144 | VALUES(1,1,1,'1'), (2,2,2,'2'), (3,3,3,'3') 145 | $$ LANGUAGE sql; 146 | 147 | CREATE RULE r1 AS ON UPDATE TO s1.r1 DO INSTEAD ( 148 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 149 | ); 150 | CREATE RULE r2 AS ON UPDATE TO s1.r2 DO INSTEAD ( 151 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 152 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 153 | ); 154 | CREATE RULE r3 AS ON UPDATE TO s1.r3 DO INSTEAD ( 155 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 156 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 157 | SELECT max(t1.c1) FROM s1.t1, s1.t2, s1.t3, s1.t4 WHERE t1.ctid = '(1,1)' AND t1.c1 = t2.c1 AND t2.ctid = '(1,1)' AND t1.c1 = t3.c1 AND t3.ctid = '(1,1)' AND t1.c1 = t4.c1 AND t4.ctid = '(1,1)'; 158 | ); 159 | CREATE RULE r1_ AS ON UPDATE TO s1.r1_ DO INSTEAD ( 160 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 161 | ); 162 | CREATE RULE r2_ AS ON UPDATE TO s1.r2_ DO INSTEAD ( 163 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 164 | SELECT max(b2t1.c1) FROM s1.t1 b2t1, s1.t2 b2t2, s1.t3 b2t3, s1.t4 b2t4 WHERE b2t1.ctid = '(1,1)' AND b2t1.c1 = b2t2.c1 AND b2t2.ctid = '(1,1)' AND b2t1.c1 = b2t3.c1 AND b2t3.ctid = '(1,1)' AND b2t1.c1 = b2t4.c1 AND b2t4.ctid = '(1,1)'; 165 | ); 166 | CREATE RULE r3_ AS ON UPDATE TO s1.r3_ DO INSTEAD ( 167 | SELECT max(b1t1.c1) FROM s1.t1 b1t1, s1.t2 b1t2, s1.t3 b1t3, s1.t4 b1t4 WHERE b1t1.ctid = '(1,1)' AND b1t1.c1 = b1t2.c1 AND b1t2.ctid = '(1,1)' AND b1t1.c1 = b1t3.c1 AND b1t3.ctid = '(1,1)' AND b1t1.c1 = b1t4.c1 AND b1t4.ctid = '(1,1)'; 168 | SELECT max(b2t1.c1) FROM s1.t1 b2t1, s1.t2 b2t2, s1.t3 b2t3, s1.t4 b2t4 WHERE b2t1.ctid = '(1,1)' AND b2t1.c1 = b2t2.c1 AND b2t2.ctid = '(1,1)' AND b2t1.c1 = b2t3.c1 AND b2t3.ctid = '(1,1)' AND b2t1.c1 = b2t4.c1 AND b2t4.ctid = '(1,1)'; 169 | SELECT max(b3t1.c1) FROM s1.t1 b3t1, s1.t2 b3t2, s1.t3 b3t3, s1.t4 b3t4 WHERE b3t1.ctid = '(1,1)' AND b3t1.c1 = b3t2.c1 AND b3t2.ctid = '(1,1)' AND b3t1.c1 = b3t3.c1 AND b3t3.ctid = '(1,1)' AND b3t1.c1 = b3t4.c1 AND b3t4.ctid = '(1,1)'; 170 | ); 171 | -------------------------------------------------------------------------------- /update_copied_funcs.pl: -------------------------------------------------------------------------------- 1 | #! /usr/bin/perl 2 | 3 | use strict; 4 | 5 | my $srcpath; 6 | my @sources = ( 7 | 'src/backend/optimizer/path/allpaths.c', 8 | 'src/backend/optimizer/path/joinrels.c'); 9 | my %defs = 10 | ('core.c' 11 | => {protos => [], 12 | funcs => ['set_plain_rel_pathlist', 13 | 'standard_join_search', 14 | 'create_plain_partial_paths', 15 | 'join_search_one_level', 16 | 'make_rels_by_clause_joins', 17 | 'make_rels_by_clauseless_joins', 18 | 'join_is_legal', 19 | 'has_join_restriction', 20 | 'restriction_is_constant_false', 21 | 'build_child_join_sjinfo', 22 | 'get_matching_part_pairs', 23 | 'compute_partition_bounds', 24 | 'try_partitionwise_join', 25 | 'free_child_join_sjinfo'], 26 | head => core_c_head()}, 27 | 'make_join_rel.c' 28 | => {protos => [], 29 | funcs => ['make_join_rel', 30 | 'populate_joinrel_with_paths'], 31 | head => make_join_rel_head()}); 32 | 33 | open (my $in, '-|', "objdump -W `which postgres`") || die "failed to objdump"; 34 | while (<$in>) 35 | { 36 | if (/DW_AT_comp_dir .*: (.*\/)src\/backend\//) 37 | { 38 | $srcpath = $1; 39 | last; 40 | } 41 | } 42 | close($in); 43 | 44 | die "source path not found" if (! defined $srcpath); 45 | #printf("Source path = %s\n", $srcpath); 46 | 47 | my %protos; 48 | my %funcs; 49 | my %func_is_static; 50 | my %func_source; 51 | 52 | for my $fname (@sources) 53 | { 54 | my $f = $srcpath.$fname; 55 | my $source; 56 | 57 | open ($in, '<', $f) || die "failed to open $f: $!"; 58 | while (<$in>) 59 | { 60 | $source .= $_; 61 | } 62 | 63 | ## Collect static prototypes 64 | 65 | while ($source =~ /\n(static [^\(\)\{\}]*?(\w+)(\([^\{\);]+?\);))/gsm) 66 | { 67 | # print "Prototype found: $2\n"; 68 | $protos{$2} = $1; 69 | } 70 | 71 | ## Collect function bodies 72 | 73 | while ($source =~ /(\n\/\*\n.+?\*\/\n(static )?(.+?)\n(.+?) *\(.*?\)\n\{.+?\n\}\n)/gsm) 74 | { 75 | $funcs{$4} = $1; 76 | $func_is_static{$4} = (defined $2); 77 | $func_source{$4} = $fname; 78 | 79 | # printf("Function found: %s$4\n", $func_is_static{$4} ? "static " : ""); 80 | } 81 | 82 | close($in); 83 | } 84 | 85 | 86 | # Generate files 87 | for my $fname (keys %defs) 88 | { 89 | my %d = %{$defs{$fname}}; 90 | 91 | my @protonames = @{$d{'protos'}}; 92 | my @funcnames = @{$d{'funcs'}}; 93 | my $head = $d{'head'}; 94 | 95 | print "Generate $fname.\n"; 96 | open (my $out, '>', $fname) || die "could not open $fname: $!"; 97 | 98 | print $out $head; 99 | 100 | for (@protonames) 101 | { 102 | print " Prototype: $_\n"; 103 | print $out "\n"; 104 | die "Prototype for $_ not found" if (! defined $protos{$_}); 105 | print $out $protos{$_}; 106 | } 107 | 108 | for (@funcnames) 109 | { 110 | printf(" %s function: $_@%s\n", 111 | $func_is_static{$_}?"static":"public", $func_source{$_}); 112 | print $out "\n"; 113 | die "Function body for $_ not found" if (! defined $funcs{$_}); 114 | print $out $funcs{$_}; 115 | } 116 | 117 | close($out); 118 | } 119 | 120 | # modify make_join_rel.c 121 | patch_make_join_rel(); 122 | 123 | sub core_c_head() 124 | { 125 | return << "EOS"; 126 | /*------------------------------------------------------------------------- 127 | * 128 | * core.c 129 | * Routines copied from PostgreSQL core distribution. 130 | * 131 | * The main purpose of this files is having access to static functions in core. 132 | * Another purpose is tweaking functions behavior by replacing part of them by 133 | * macro definitions. See at the end of pg_hint_plan.c for details. Anyway, 134 | * this file *must* contain required functions without making any change. 135 | * 136 | * This file contains the following functions from corresponding files. 137 | * 138 | * src/backend/optimizer/path/allpaths.c 139 | * 140 | * public functions: 141 | * standard_join_search(): This funcion is not static. The reason for 142 | * including this function is make_rels_by_clause_joins. In order to 143 | * avoid generating apparently unwanted join combination, we decided to 144 | * change the behavior of make_join_rel, which is called under this 145 | * function. 146 | * 147 | * static functions: 148 | * set_plain_rel_pathlist() 149 | * create_plain_partial_paths() 150 | * 151 | * src/backend/optimizer/path/joinrels.c 152 | * 153 | * public functions: 154 | * join_search_one_level(): We have to modify this to call my definition of 155 | * make_rels_by_clause_joins. 156 | * 157 | * static functions: 158 | * make_rels_by_clause_joins() 159 | * make_rels_by_clauseless_joins() 160 | * join_is_legal() 161 | * has_join_restriction() 162 | * restriction_is_constant_false() 163 | * build_child_join_sjinfo() 164 | * get_matching_part_pairs() 165 | * compute_partition_bounds() 166 | * try_partitionwise_join() 167 | * 168 | * Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group 169 | * Portions Copyright (c) 1994, Regents of the University of California 170 | * 171 | *------------------------------------------------------------------------- 172 | */ 173 | 174 | #include "access/tsmapi.h" 175 | #include "catalog/pg_operator.h" 176 | #include "foreign/fdwapi.h" 177 | EOS 178 | } 179 | 180 | sub make_join_rel_head 181 | { 182 | return << "EOS"; 183 | /*------------------------------------------------------------------------- 184 | * 185 | * make_join_rel.c 186 | * Routines copied from PostgreSQL core distribution with some 187 | * modifications. 188 | * 189 | * src/backend/optimizer/path/joinrels.c 190 | * 191 | * This file contains the following functions from corresponding files. 192 | * 193 | * static functions: 194 | * make_join_rel() 195 | * populate_joinrel_with_paths() 196 | * 197 | * Portions Copyright (c) 2013-2024, NIPPON TELEGRAPH AND TELEPHONE CORPORATION 198 | * Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group 199 | * Portions Copyright (c) 1994, Regents of the University of California 200 | * 201 | *------------------------------------------------------------------------- 202 | */ 203 | 204 | /* 205 | * adjust_rows: tweak estimated row numbers according to the hint. 206 | */ 207 | static double 208 | adjust_rows(double rows, RowsHint *hint) 209 | { 210 | double result = 0.0; /* keep compiler quiet */ 211 | 212 | if (hint->value_type == RVT_ABSOLUTE) 213 | result = hint->rows; 214 | else if (hint->value_type == RVT_ADD) 215 | result = rows + hint->rows; 216 | else if (hint->value_type == RVT_SUB) 217 | result = rows - hint->rows; 218 | else if (hint->value_type == RVT_MULTI) 219 | result = rows * hint->rows; 220 | else 221 | Assert(false); /* unrecognized rows value type */ 222 | 223 | hint->base.state = HINT_STATE_USED; 224 | if (result < 1.0) 225 | ereport(WARNING, 226 | (errmsg("Force estimate to be at least one row, to avoid possible divide-by-zero when interpolating costs : %s", 227 | hint->base.hint_str))); 228 | result = clamp_row_est(result); 229 | elog(DEBUG1, "adjusted rows %d to %d", (int) rows, (int) result); 230 | 231 | return result; 232 | } 233 | EOS 234 | } 235 | 236 | 237 | sub patch_make_join_rel 238 | { 239 | open(my $out, '|-', 'patch') || die "failed to open pipe: $!"; 240 | 241 | print $out <<"EOS"; 242 | diff --git b/make_join_rel.c a/make_join_rel.c 243 | index 0e7b99f..287e7f1 100644 244 | --- b/make_join_rel.c 245 | +++ a/make_join_rel.c 246 | @@ -126,6 +126,84 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2) 247 | joinrel = build_join_rel(root, joinrelids, rel1, rel2, sjinfo, 248 | &restrictlist); 249 | 250 | + /* !!! START: HERE IS THE PART WHICH IS ADDED FOR PG_HINT_PLAN !!! */ 251 | + { 252 | + RowsHint *rows_hint = NULL; 253 | + int i; 254 | + RowsHint *justforme = NULL; 255 | + RowsHint *domultiply = NULL; 256 | + 257 | + /* Search for applicable rows hint for this join node */ 258 | + for (i = 0; i < current_hint_state->num_hints[HINT_TYPE_ROWS]; i++) 259 | + { 260 | + rows_hint = current_hint_state->rows_hints[i]; 261 | + 262 | + /* 263 | + * Skip this rows_hint if it is invalid from the first or it 264 | + * doesn't target any join rels. 265 | + */ 266 | + if (!rows_hint->joinrelids || 267 | + rows_hint->base.state == HINT_STATE_ERROR) 268 | + continue; 269 | + 270 | + if (bms_equal(joinrelids, rows_hint->joinrelids)) 271 | + { 272 | + /* 273 | + * This joinrel is just the target of this rows_hint, so tweak 274 | + * rows estimation according to the hint. 275 | + */ 276 | + justforme = rows_hint; 277 | + } 278 | + else if (!(bms_is_subset(rows_hint->joinrelids, rel1->relids) || 279 | + bms_is_subset(rows_hint->joinrelids, rel2->relids)) && 280 | + bms_is_subset(rows_hint->joinrelids, joinrelids) && 281 | + rows_hint->value_type == RVT_MULTI) 282 | + { 283 | + /* 284 | + * If the rows_hint's target relids is not a subset of both of 285 | + * component rels and is a subset of this joinrel, ths hint's 286 | + * targets spread over both component rels. This menas that 287 | + * this hint has been never applied so far and this joinrel is 288 | + * the first (and only) chance to fire in current join tree. 289 | + * Only the multiplication hint has the cumulative nature so we 290 | + * apply only RVT_MULTI in this way. 291 | + */ 292 | + domultiply = rows_hint; 293 | + } 294 | + } 295 | + 296 | + if (justforme) 297 | + { 298 | + /* 299 | + * If a hint just for me is found, no other adjust method is 300 | + * useles, but this cannot be more than twice becuase this joinrel 301 | + * is already adjusted by this hint. 302 | + */ 303 | + if (justforme->base.state == HINT_STATE_NOTUSED) 304 | + joinrel->rows = adjust_rows(joinrel->rows, justforme); 305 | + } 306 | + else 307 | + { 308 | + if (domultiply) 309 | + { 310 | + /* 311 | + * If we have multiple routes up to this joinrel which are not 312 | + * applicable this hint, this multiply hint will applied more 313 | + * than twice. But there's no means to know of that, 314 | + * re-estimate the row number of this joinrel always just 315 | + * before applying the hint. This is a bit different from 316 | + * normal planner behavior but it doesn't harm so much. 317 | + */ 318 | + set_joinrel_size_estimates(root, joinrel, rel1, rel2, sjinfo, 319 | + restrictlist); 320 | + 321 | + joinrel->rows = adjust_rows(joinrel->rows, domultiply); 322 | + } 323 | + 324 | + } 325 | + } 326 | + /* !!! END: HERE IS THE PART WHICH IS ADDED FOR PG_HINT_PLAN !!! */ 327 | + 328 | /* 329 | * If we've already proven this join is empty, we needn't consider any 330 | * more paths for it. 331 | EOS 332 | } 333 | --------------------------------------------------------------------------------