Skip to content
GitLab
Explore
Sign in
Primary navigation
Search or go to…
Project
S
SQL Scripts
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Build
Pipelines
Jobs
Pipeline schedules
Artifacts
Deploy
Releases
Harbor Registry
Model registry
Operate
Environments
Monitor
Incidents
Analyze
Value stream analytics
Contributor analytics
CI/CD analytics
Repository analytics
Model experiments
Help
Help
Support
GitLab documentation
Compare GitLab plans
Community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
HOTMapper
SQL Scripts
Commits
6ef954a8
Commit
6ef954a8
authored
6 years ago
by
jvfpw18
Browse files
Options
Downloads
Patches
Plain Diff
Add matricula_por_localizacao, aggregate to be used in classroom_count
parent
6efa1369
No related branches found
No related tags found
No related merge requests found
Changes
1
Show whitespace changes
Inline
Side-by-side
Showing
1 changed file
matricula_por_localizacao.sql
+68
-0
68 additions, 0 deletions
matricula_por_localizacao.sql
with
68 additions
and
0 deletions
matricula_por_localizacao.sql
0 → 100644
+
68
−
0
View file @
6ef954a8
/*
Copyright (C) 2016 Centro de Computacao Cientifica e Software Livre
Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR
This file is part of HOTMapper.
HOTMapper is free software: you can redistribute it and/or modify
it under the terms of the GNU General Public License as published by
the Free Software Foundation, either version 3 of the License, or
(at your option) any later version.
HOTMapper is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU General Public License for more details.
You should have received a copy of the GNU General Public License
along with HOTMapper. If not, see <https://www.gnu.org/licenses/>.
*/
-- depends: matricula 2017+
-- SimCAQ: tabela de projeção de matrículas --
CREATE
TABLE
matricula_por_localizacao
AS
(
WITH
day_count
AS
(
SELECT
count
(
*
)
as
dia_total
,
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
FROM
matricula
WHERE
tipo
<=
3
AND
dependencia_adm_id
<
4
AND
ano_censo
>=
2017
AND
(
turma_turno_id
IN
(
1
,
2
,
99
)
OR
turma_turno_id
IS
null
)
GROUP
BY
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
ORDER
BY
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
),
night_count
AS
(
SELECT
count
(
*
)
as
noite_total
,
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
FROM
matricula
WHERE
tipo
<=
3
AND
dependencia_adm_id
<
4
AND
ano_censo
>=
2017
AND
turma_turno_id
=
3
GROUP
BY
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
ORDER
BY
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
localizacao_id
)
SELECT
matricula
.
ano_censo
,
matricula
.
estado_id
,
matricula
.
municipio_id
,
matricula
.
serie_ano_id
,
COALESCE
(
dia_total
,
0
)
AS
dia_total
,
COALESCE
(
noite_total
,
0
)
AS
noite_total
,
matricula
.
localizacao_id
FROM
matricula
LEFT
JOIN
day_count
ON
matricula
.
ano_censo
=
day_count
.
ano_censo
AND
matricula
.
estado_id
=
day_count
.
estado_id
AND
matricula
.
municipio_id
=
day_count
.
municipio_id
AND
matricula
.
serie_ano_id
=
day_count
.
serie_ano_id
AND
matricula
.
localizacao_id
=
day_count
.
localizacao_id
LEFT
JOIN
night_count
ON
matricula
.
ano_censo
=
night_count
.
ano_censo
AND
matricula
.
estado_id
=
night_count
.
estado_id
AND
matricula
.
municipio_id
=
night_count
.
municipio_id
AND
matricula
.
serie_ano_id
=
night_count
.
serie_ano_id
AND
matricula
.
localizacao_id
=
night_count
.
localizacao_id
WHERE
matricula
.
ano_censo
>=
2017
AND
matricula
.
serie_ano_id
IS
NOT
NULL
AND
matricula
.
tipo
<=
3
AND
matricula
.
dependencia_adm_id
<
4
GROUP
BY
matricula
.
ano_censo
,
matricula
.
estado_id
,
matricula
.
municipio_id
,
matricula
.
serie_ano_id
,
dia_total
,
noite_total
,
matricula
.
localizacao_id
);
-- Create serie mod
INSERT
INTO
matricula_por_localizacao
(
ano_censo
,
estado_id
,
municipio_id
,
serie_ano_id
,
dia_total
,
noite_total
,
localizacao_id
)
SELECT
ano_censo
,
estado_id
,
municipio_id
,
LEFT
(
serie_ano_id
,
1
)
as
serie
,
sum
(
dia_total
),
sum
(
noite_total
),
localizacao_id
FROM
matricula_por_localizacao
GROUP
BY
ano_censo
,
estado_id
,
municipio_id
,
serie
,
localizacao_id
;
\ No newline at end of file
This diff is collapsed.
Click to expand it.
Preview
0%
Loading
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment