DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Generative AI has transformed nearly every industry. How can you leverage GenAI to improve your productivity and efficiency?

SBOMs are essential to circumventing software supply chain attacks, and they provide visibility into various software components.

Related

  • Recovering an MS SQL Database From Suspect Mode: Step-By-Step Guide
  • Instant Integrations With API and Logic Automation
  • The Ultimate Guide To Repair MySQL Database
  • Are You Facing an Error When You Run the StartDagServerMaintenance.ps1 Script?

Trending

  • Designing Microservices Architecture With a Custom Spring Boot Starter and Auto-Configuration Framework
  • Stop Building Monolithic AI Brains, Build a Specialist Team Instead
  • Why Traditional CI/CD Falls Short for Cloud Infrastructure
  • How We Broke the Monolith (and Kept Our Sanity): Lessons From Moving to Microservices
  1. DZone
  2. Data Engineering
  3. Databases
  4. Revealing the Queries Behind Psql's Backslash Commands

Revealing the Queries Behind Psql's Backslash Commands

Psql has a lot of super useful backslash commands, but sometimes it's even more useful to know the queries behind them.

By 
Dustin Marx user avatar
Dustin Marx
·
Feb. 06, 19 · Tutorial
Likes (1)
Comment
Save
Tweet
Share
13.8K Views

Join the DZone community and get the full member experience.

Join For Free

PostgreSQL's psql interactive terminal tool provides several useful "backslash list commands" such as \d (lists "relations" such as tables, views, indexes, and sequences), \dt (lists tables), \di (lists indexes), \ds (lists sequences), \dv (lists views), \df (lists functions), \du (lists roles), and \? (displays help/usage details on backslash commands). These commands are concise and much simpler to use than writing the queries against PostgreSQL system catalogs ( pg_class, pg_roles, pg_namespace, pg_trigger, pg_index, etc.) and information_schema that would provide the same types of details.

Although the psql backslash commands are easier to use than their associated queries, there are situations when it is important to know the full query behind a particular command. These situations include needing to perform a slightly different/adapted query from that associated with the pre-built command and needing to perform similar queries in scripts or code that are being used as PostgreSQL clients instead of psql. These situations make it important to be able to determine what queries psql is performing and the psql option -E (or --echo-hidden) allow that.

The PostgreSQL psql documentation states that the psql options -E and --echo-hidden "echo the actual queries generated by \d and other backslash commands." The documentation adds commentary on why this is useful. "You can use this to study psql's internal operations." When psql is started with the -E or --echo-hidden options, it will display the query associated with a backslash command before executing that command. The next screen snapshot illustrates this for the \du command used to show roles.

From use of psql -E and execution of the command \du, we're able to see that the query underling \du is this:

SELECT r.rolname, r.rolsuper, r.rolinherit,
  r.rolcreaterole, r.rolcreatedb, r.rolcanlogin,
  r.rolconnlimit, r.rolvaliduntil,
  ARRAY(SELECT b.rolname
        FROM pg_catalog.pg_auth_members m
        JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid)
        WHERE m.member = r.oid) as memberof
, r.rolreplication
, r.rolbypassrls
FROM pg_catalog.pg_roles r
WHERE r.rolname !~ '^pg_'
ORDER BY 1;

Although the query is not nearly as nice to use as \du, we are now able to adapt this query for a related but different use case and are able to run this query from a PostgreSQL client other than psql.

Database Command (computing)

Published at DZone with permission of Dustin Marx, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • Recovering an MS SQL Database From Suspect Mode: Step-By-Step Guide
  • Instant Integrations With API and Logic Automation
  • The Ultimate Guide To Repair MySQL Database
  • Are You Facing an Error When You Run the StartDagServerMaintenance.ps1 Script?

Partner Resources

×

Comments

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • [email protected]

Let's be friends: