Buscar en moleculax

Este blog es un ensayo digital donde el pensamiento estructurado se encuentra con la introspección profunda. Explora la arquitectura del conocimiento: desde lo técnico hasta los fundamentos éticos. Aquí, cada algoritmo tiene propósito, cada línea de código refleja intención, y cada reflexión filosófica busca optimizar no solo sistemas, sino también decisiones humanas. Este blog no solo enseña a pensar, enseña a discernir, a construir con sentido. Porque el verdadero desarrollo nace de la conciencia, y eso exige precisión, virtud y coraje.

Tenemos que aprender a contemplar las potenciales consecuencias de nuestros planes, para impedir que nos sorprendan. De esta manera, tendremos más control sobre las situaciones difíciles ya que el verdadero progreso no se mide por la velocidad con la que avanzamos, sino por la dirección que elegimos. En un mundo cada vez más interconectado, el desarrollo de la humanidad exige más que tecnología y conocimiento: requiere conciencia, empatía y propósito.

Debemos cultivar una inteligencia que no solo resuelva problemas, sino que los prevenga con sabiduría. Una ciencia que no solo descubra, sino que se pregunte por qué y para quién. Una economía que no solo crezca, sino que reparta con justicia. Y una cultura que no solo celebre lo diverso, sino que lo abrace como fuerza vital.

Cada decisión que tomamos, cada palabra que decimos, cada idea que compartimos, puede ser una semilla de transformación. El futuro no está escrito: lo estamos escribiendo juntos, ahora mismo.

Que el desarrollo humano sea integral, sostenible y profundamente humano. Porque solo cuando elevamos a todos, nos elevamos como especie.

Sabiduría Justicia Templanza Coraje
PostgreSQL - DATEDIFF - Datetime Difference in Seconds, Days, Months, Weeks etc

You can use various datetime expressions or a user-defined DATEDIFF function (UDF) to calculate the difference between 2 datetime values in seconds, minutes, hours, days, weeks, months and years in PostgreSQL.

Overview

PostgreSQL does not provide DATEDIFF function similar to SQL Server DATEDIFF, but you can use various expressions or UDF to get the same results.
SQL Server and SybasePostgreSQL
YearsDATEDIFF(yy, start, end)DATE_PART('year', end) - DATE_PART('year', start)
MonthsDATEDIFF(mm, start, end)years_diff * 12 + (DATE_PART('month', end) - DATE_PART('month', start))
DaysDATEDIFF(dd, start, end)DATE_PART('day', end - start)
WeeksDATEDIFF(wk, start, end)TRUNC(DATE_PART('day', end - start)/7)
HoursDATEDIFF(hh, start, end)days_diff * 24 + DATE_PART('hour', end - start )
MinutesDATEDIFF(mi, start, end)hours_diff * 60 + DATE_PART('minute', end - start )
SecondsDATEDIFF(ss, start, end)minutes_diff * 60 + DATE_PART('minute', end - start )
Version: PostgreSQL 9.1

PostgreSQL - Date Difference in Years

Consider SQL Server function to calculate the difference between 2 dates in years:
SQL Server:
  -- Difference between Oct 02, 2011 and Jan 01, 2012 in years
  SELECT DATEDIFF(year, '2011-10-02', '2012-01-01');
  -- Result: 1
Note that SQL Server DATEDIFF function returned 1 year although there are only 3 months between dates.
SQL Server does not count full years passed between the dates, it calculates the difference between the year parts only.
In PostgreSQL, you can get the year parts from the dates and subtract them.
PostgreSQL:
  -- Difference between Oct 02, 2011 and Jan 01, 2012 in years
  SELECT DATE_PART('year', '2012-01-01'::date) - DATE_PART('year', '2011-10-02'::date);
  -- Result: 1

PostgreSQL - Date Difference in Months

Consider SQL Server function to calculate the difference between 2 dates in months:
SQL Server:
  -- Difference between Oct 02, 2011 and Jan 01, 2012 in months
  SELECT DATEDIFF(month, '2011-10-02', '2012-01-01');
  -- Result: 3
In PostgreSQL, you can take the difference in years, multiply by 12 and add the difference between month parts that can be negative.
PostgreSQL:
  -- Difference between Oct 02, 2011 and Jan 01, 2012 in months
  SELECT (DATE_PART('year', '2012-01-01'::date) - DATE_PART('year', '2011-10-02'::date)) * 12 +
              (DATE_PART('month', '2012-01-01'::date) - DATE_PART('month', '2011-10-02'::date));
  -- Result: 3

PostgreSQL - Date Difference in Days

Consider SQL Server function to calculate the difference between 2 dates in days:
SQL Server:
  -- Difference between Dec 29, 2011 23:00 and Dec 31, 2011 01:00 in days
  SELECT DATEDIFF(day, '2011-12-29 23:00:00', '2011-12-31 01:00:00');
  -- Result: 2
Note that DATEDIFF returned 2 days, although there is only 1 day and 2 hours between the datetime values.
In PostgreSQL, if you subtract one datetime value (TIMESTAMP, DATE or TIME data type) from another, you will get an INTERVAL value in the form ”ddd days hh:mi:ss”.
    SELECT '2011-12-31 01:00:00'::timestamp - '2011-12-29 23:00:00'::timestamp;
    -- Result: "1 day 02:00:00" 
 
    SELECT '2011-12-31 01:00:00'::timestamp - '2010-09-17 23:00:00'::timestamp;
    -- Result: "469 days 02:00:00"
So you can use DATE_PART function to extact the number of days, but it returns the number of full days between the dates.
PostgreSQL:
  -- Difference between Dec 29, 2011 23:00 and Dec 31, 2011 01:00 in days
  SELECT DATE_PART('day', '2011-12-31 01:00:00'::timestamp - '2011-12-29 23:00:00'::timestamp);
  -- Result: 1

PostgreSQL - Date Difference in Weeks

Consider SQL Server function to calculate the difference between 2 dates in weeks:
SQL Server:
  -- Difference between Dec 22, 2011 and Dec 31, 2011 in weeks
  SELECT DATEDIFF(week, '2011-12-22', '2011-12-31');
  -- Result: 1
DATEDIFF returnes the number of full weeks between the datetime values.
In PostgreSQL, you can use an expression to define the number of days (see above) and divide it by 7. TRUNC is required to remove the decimal part after the division.
PostgreSQL:
  -- Difference between Dec 22, 2011 and Dec 31, 2011 in weeks
  SELECT TRUNC(DATE_PART('day', '2011-12-31'::timestamp - '2011-12-22'::timestamp)/7);
  -- Result: 1

PostgreSQL - Datetime Difference in Hours

Consider SQL Server function to calculate the difference between 2 datetime value in hours:
SQL Server:
  -- Difference between Dec 30, 2011 08:55 and Dec 30, 2011 9:05 in weeks
  SELECT DATEDIFF(hour, '2011-12-30 08:55', '2011-12-30 09:05');
  -- Result: 1
Note that DATEDIFF returned 1 hour although there is just 10 minutes difference between the datetime values.
In PostgreSQL, you can use an expression to define the number of days (see above), multiple by 24 and add the difference is hours.
PostgreSQL:
  -- Difference between Dec 30, 2011 08:55 and Dec 30, 2011 9:05 in weeks
  SELECT DATE_PART('day', '2011-12-30 08:55'::timestamp - '2011-12-30 09:05'::timestamp) * 24 + 
              DATE_PART('hour', '2011-12-30 08:55'::timestamp - '2011-12-30 09:05'::timestamp);
  -- Result: 0
Note that this PostreSQL expression returns the number of full hours passed between the datetime values.

PostgreSQL - Datetime Difference in Minutes

Consider SQL Server function to calculate the difference between 2 datetime values in minutes:
SQL Server:
  -- Difference between Dec 30, 2011 08:54:55 and  Dec 30, 2011 08:56:10 in minutes
  SELECT DATEDIFF(minute, '2011-12-30 08:54:55', '2011-12-30 08:56:10');
  -- Result: 2
 
  -- Time only
  SELECT DATEDIFF(minute, '08:54:55', '08:56:10');
  -- Result: 2
Note that DATEDIFF returned 2 minutes although there is just 1 minute and 15 seconds between the datetime values.
In PostgreSQL, you can use an expression to define the number of hours (see above), multiple by 60 and add the difference is minutes.
PostgreSQL:
  -- Difference between Dec 30, 2011 08:54:55 and  Dec 30, 2011 08:56:10 in minutes
  SELECT (DATE_PART('day', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp) * 24 + 
               DATE_PART('hour', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp)) * 60 +
               DATE_PART('minute', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp);
  -- Result: 1
 
  -- Time only
  SELECT DATE_PART('hour', '08:56:10'::time - '08:54:55'::time) * 60 +
              DATE_PART('minute', '08:56:10'::time - '08:54:55'::time);
  -- Result: 1
Note that these PostreSQL expressions return the number of full minutes passed between the datetime values.

PostgreSQL - Datetime Difference in Seconds

Consider SQL Server function to calculate the difference between 2 datetime values in seconds:
SQL Server:
  -- Difference between Dec 30, 2011 08:54:55 and  Dec 30, 2011 08:56:10 in seconds
  SELECT DATEDIFF(second, '2011-12-30 08:54:55', '2011-12-30 08:56:10');
  -- Result: 75
 
  -- Time only
  SELECT DATEDIFF(second, '08:54:55', '08:56:10');
  -- Result: 75
In PostgreSQL, you can use an expression to define the number of minutes (see above), multiple by 60 and add the difference is seconds.
PostgreSQL:
  -- Difference between Dec 30, 2011 08:54:55 and  Dec 30, 2011 08:56:10 in seconds
  SELECT ((DATE_PART('day', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp) * 24 + 
                DATE_PART('hour', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp)) * 60 +
                DATE_PART('minute', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp)) * 60 +
                DATE_PART('second', '2011-12-30 08:56:10'::timestamp - '2011-12-30 08:54:55'::timestamp);
  -- Result: 75
 
  -- Time only
  SELECT (DATE_PART('hour', '08:56:10'::time - '08:54:55'::time) * 60 +
               DATE_PART('minute', '08:56:10'::time - '08:54:55'::time)) * 60 +
               DATE_PART('second', '08:56:10'::time - '08:54:55'::time);
  -- Result: 75

PostgreSQL DATEDIFF - User-Defined Function (UDF)

Besides a separate expression to calculate the datetime difference for each time unit, you can use a function similar to SQL Server DATEDIFF function.
PostgreSQL:
   CREATE OR REPLACE FUNCTION DateDiff (units VARCHAR(30), start_t TIMESTAMP, end_t TIMESTAMP) 
     RETURNS INT AS $$
   DECLARE
     diff_interval INTERVAL; 
     diff INT = 0;
     years_diff INT = 0;
   BEGIN
     IF units IN ('yy', 'yyyy', 'year', 'mm', 'm', 'month') THEN
       years_diff = DATE_PART('year', end_t) - DATE_PART('year', start_t);
 
       IF units IN ('yy', 'yyyy', 'year') THEN
         -- SQL Server does not count full years passed (only difference between year parts)
         RETURN years_diff;
       ELSE
         -- If end month is less than start month it will subtracted
         RETURN years_diff * 12 + (DATE_PART('month', end_t) - DATE_PART('month', start_t)); 
       END IF;
     END IF;
 
     -- Minus operator returns interval 'DDD days HH:MI:SS'  
     diff_interval = end_t - start_t;
 
     diff = diff + DATE_PART('day', diff_interval);
 
     IF units IN ('wk', 'ww', 'week') THEN
       diff = diff/7;
       RETURN diff;
     END IF;
 
     IF units IN ('dd', 'd', 'day') THEN
       RETURN diff;
     END IF;
 
     diff = diff * 24 + DATE_PART('hour', diff_interval); 
 
     IF units IN ('hh', 'hour') THEN
        RETURN diff;
     END IF;
 
     diff = diff * 60 + DATE_PART('minute', diff_interval);
 
     IF units IN ('mi', 'n', 'minute') THEN
        RETURN diff;
     END IF;
 
     diff = diff * 60 + DATE_PART('second', diff_interval);
 
     RETURN diff;
   END;
   $$ LANGUAGE plpgsql;

How to Use PostgreSQL DATEDIFF Function

The syntax is similar to SQL Server DATEDIFF, but you have to specify a time unit (second, minute etc. and their abbreviations) as a string literal in PostgreSQL, for example:
    -- Difference between Dec 30, 2011 08:54:55 and  Dec 30, 2011 08:56:10 in seconds
  SELECT DATEDIFF('second', '2011-12-30 08:54:55'::timestamp, '2011-12-30 08:56:10'::timestamp);
  -- Result: 75

PostgreSQL DATEDIFF Function for TIME Only

You can have another function that operates on time data types only. PostgreSQL supports overloaded functions having the same name, but different data types of parameters:
   CREATE OR REPLACE FUNCTION DateDiff (units VARCHAR(30), start_t TIME, end_t TIME) 
     RETURNS INT AS $$
   DECLARE
     diff_interval INTERVAL; 
     diff INT = 0;
   BEGIN
     -- Minus operator for TIME returns interval 'HH:MI:SS'  
     diff_interval = end_t - start_t;
 
     diff = DATE_PART('hour', diff_interval);
 
     IF units IN ('hh', 'hour') THEN
       RETURN diff;
     END IF;
 
     diff = diff * 60 + DATE_PART('minute', diff_interval);
 
     IF units IN ('mi', 'n', 'minute') THEN
        RETURN diff;
     END IF;
 
     diff = diff * 60 + DATE_PART('second', diff_interval);
 
     RETURN diff;
   END;
   $$ LANGUAGE plpgsql;
For example, you can call this function as:
  -- Difference between 08:54:55 and 08:56:10 in seconds
  SELECT DATEDIFF('second', '08:54:55'::time, '08:56:10'::time);
  -- Result: 75

Resources

.

15dias (4) agenda 2023 (1) Algo que leer (268) Android (2) Angular (2) Apache (6) API (1) Arte y Cultura (11) Artes Marciales (10) Astro (1) Banner (1) Base de datos (36) Batalla Cultural (5) Big Data (12) Budismo (4) cabala judia (2) Calculo Asistido por computadoras (2) Canaima (6) Caos (1) Ceo (1) ciencias (2) Cine (1) Cobol (12) Cobra Kai (1) Codigo Linux Documental (2) Computación (3) Computación forense (14) Configurando Samba (1) Conocimiento (1) Consola (8) contenedores (9) cosmo (2) Criptomonedas (3) Cultura (1) Cursos (16) Darkweeb (3) Data Mining (1) Debian (18) Deep Learning (2) DeepWeb (7) demografia (9) Deporte y Recreación (9) Deportes (10) desclasificados (7) Desktop (1) developers (1) DevOps (1) Docker (11) Document (1) Ecología (6) Editor (3) Editores (4) Educacion y TIC (31) Electronica (2) Empleos (1) Emprendimiento (7) Espiritualidad (2) estoicismo (4) Eventos (2) Excel (1) Express (1) fedora (1) Filosofía (25) Fisica (1) Flisol 2008 (3) Flisol 2010 (1) Flisol 2015 (1) framework (2) Funny (1) Geografía (1) Gerencia y Liderazgo (72) Gestor de Volúmenes Lógicos (1) Git (7) GitHub (8) Globalizacion (5) gnu (28) Go (1) gobiernos (2) golang (2) Google por dentro (1) GraphQL (1) gRPC (1) Hackers - Documental (8) Hacking (31) Historia (3) howto (189) html (1) IA (22) IntelliJIDEA (1) Internet (6) Introducción a los patrones (2) J SON (1) java (55) java eclipse (3) javaScript (9) JDK (1) jiujitsu (4) Json (1) Junit (1) kali (39) kernel (2) Kotlin (1) Laravel (2) Latin (1) lecturas (2) LIbreOffice (1) Libros (4) Linux (48) Linux VirtualBox (1) Literatura (1) Machine Learning (2) Manuales (42) mariaDB (2) Markdown (4) Marketing (1) Matando ladilla (9) Matematicas (3) Matematricas (1) Math (1) maven (1) metodos https (1) Modelos (1) MongoDB (17) Multimedia (1) Musica (1) mvc (2) Mysql (22) MySQL Workbench (1) Nagios (2) Naturismo (1) NextJS (2) node (5) Node.js (6) NodeJS (9) NoSQL (1) npm (1) Oracle (10) Oracle sql (10) Php (3) PL/SQL (1) Plsql (1) PNL (1) Poblacion (2) Podman (1) Poesia (1) Politica (5) Política (1) Postgresql (11) PowerShell (1) programacion (86) Psicologia (11) Python (7) React (4) Recomiendo (1) Redes (31) Redis (2) Religion (2) REST (2) Rock (1) Rock/Metal Mp3 (2) RUP (1) Salud (5) sc:snap:android-studio (1) sc:snap:datagrip (1) sc:snap:gitkraken linux (1) Seguridad (18) Seguridad con Gnu Privacy (2) Seo (1) simulaEntrevistas (10) simularExamen (10) Sistemas Operativos (69) SOAP (1) Sociedad (5) Software Libre (169) Soporte Tecnico (12) Sphinx (1) spring (1) spring boot (11) SQL (3) SQL en postgreSQL (41) Taekwondo (11) Tecnologia (5) Tecnología (27) Templarios (5) Tendencias (1) Tensorflow (4) Thymeleaf (1) Tomcat (2) Tor (9) Trialectica (3) TYPEACRIPT (1) Ubuntu (5) unix (2) Vida activa (1) Videos (11) Videos Educativos (10) Vim (1) Viral (3) Visual Studio (1) wallpaper (2) web (1) Wifi (2) Windows (3) WWW (2) Xrandr (1) Zero Trust (2)

Sabiduria Justicia Templanza Coraje.

Hay que contemplar las potenciales consecuencias de nuestros planes, para impedir que nos sorprendan. De esta manera, tendremos más control sobre las situaciones difíciles.


Powered by

Moleculax es un blog de ciencia, biología, astronomía, tecnología y reflexiones sobre el futuro de la humanidad. Explora ideas innovadoras, descubrimientos científicos y conocimientos que inspiran la curiosidad y la imaginación. ¿Cómo saber si te han bloqueado en WhatsApp?, ¿COMO PROGRAMAR?, דודו פארוק, ¿QUES ES estructurada,modular, MongoDBSpain CheetSheet, ORIENTADA A OBJETOS?, Bases de datos estáticas, base de datos dinamicas bases de datos nosql, estructuras de base de datos, Bases de datos de texto completo, base de datos gerarquicas HTML, CSS, XML, JavaScript, mysql, oracle, postgresql, C, C#, php, java, python, liderazgo, libros, books, informix, ¿COMO REPARAR PAQUETES ROTOS EN DEBIAN?, REPARAR paquetes ROTOS ubuntu gerencia, COMO APRENDER laravel, ACTIVAR wifi en CANAIMA, exotics, exoticas, COMO APRENDER MONGODB, agapornio, agapomis, seguros, ganar dinero, bitcoin, freeBitcoin invertir en bolsa, marketing online, ofertas de coches Описание Блога Moleculax Moleculax — это цифровое эссе, в котором структурированное мышление встречается с глубокой интроспекцией. Наш блог исследует архитектуру знаний: от технических тонкостей разработки программного обеспечения до этических основ и философии. Ключевые Темы: Разработка и Технологии: Программирование, базы данных (SQL, NoSQL), Big Data, Node.js, Java. Наука и Мышление: Астрономия, биология, научные открытия, а также такие философские направления, как Стоицизм. Этика и Будущее: Размышления о развитии человечества, моральные принципы в технологиях и этические вызовы. Наша миссия: Развивать интеллект, который не только решает проблемы, но и предотвращает их с мудростью. Moleculax 是一个关于科学、生物学、天文学、技术以及人类未来思考的博客。它探索创新的理念、科学发现和能够激发好奇心与想象力的知识。 如何知道你在 WhatsApp 上被拉黑?如何编程? דודו פארוק,什么是结构化、模块化、面向对象?MongoDBSpain 速查表,静态数据库、动态数据库、NoSQL 数据库、数据库结构、全文数据库、层次型数据库。 HTML、CSS、XML、JavaScript、MySQL、Oracle、PostgreSQL、C、C#、PHP、Java、Python,领导力、书籍、Informix。如何修复 Debian 中损坏的软件包?修复 Ubuntu 损坏的软件包,管理,如何学习 Laravel,如何在 Canaima 激活 WiFi,异域、奇异,如何学习 MongoDB,爱情鸟、保险、赚钱、比特币、FreeBitcoin、投资股票市场、网络营销、汽车优惠。 Moleculax 博客描述: Moleculax 是一篇数字随笔,在这里结构化的思维与深刻的自省相遇。我们的博客探索知识的架构:从软件开发的技术细节到伦理基础与哲学。 核心主题: - 开发与技术:编程、数据库(SQL、NoSQL)、大数据、Node.js、Java。 - 科学与思维:天文学、生物学、科学发现,以及诸如斯多葛主义等哲学流派。 - 伦理与未来:关于人类发展的思考、技术中的道德原则与伦理挑战。 我们的使命:培养一种不仅能解决问题,而且能以智慧预防问题的智能。