Skip to content

Instantly share code, notes, and snippets.

@jruizvar
Last active May 16, 2019 01:17
Show Gist options
  • Save jruizvar/a986597b123a2def2aa1e65166636832 to your computer and use it in GitHub Desktop.
Save jruizvar/a986597b123a2def2aa1e65166636832 to your computer and use it in GitHub Desktop.
Filtra empresas com historico complete, calcula o acumulado, e pivota o resultado.
DROP TABLE IF EXISTS temp1;
CREATE TABLE temp1 (anomes INT, cnpj STRING, x DOUBLE);
INSERT INTO temp1 VALUES
(201801, 'c0', 1),
(201801, 'c1', 1),
(201801, 'c2', 3),
(201802, 'c0', 2),
(201802, 'c1', 2),
(201802, 'c2', 4),
(201803, 'c0', 2),
(201803, 'c1', 1),
(201803, 'c2', 2),
(201804, 'c0', null),
(201804, 'c1', 2),
(201804, 'c2', 5);
SELECT
cnpj,
collect_set(mes01)[0] AS mes01,
collect_set(mes02)[0] AS mes02,
collect_set(mes03)[0] AS mes03,
collect_set(mes04)[0] AS mes04
FROM (
SELECT
cnpj,
CASE WHEN anomes=201801 THEN cumx END AS mes01,
CASE WHEN anomes=201802 THEN cumx END AS mes02,
CASE WHEN anomes=201803 THEN cumx END AS mes03,
CASE WHEN anomes=201804 THEN cumx END AS mes04
FROM (
SELECT
cnpj,
anomes,
sum(x) OVER w AS cumx
FROM (
SELECT
cnpj,
anomes,
x,
count(x) OVER (PARTITION BY cnpj) AS countx
FROM temp1
) t0
WHERE countx = 4 -- filtra empresas com historico completo
WINDOW w AS
(
PARTITION BY cnpj
ORDER BY anomes
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
)
) t1
) t2
GROUP BY cnpj;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment