-
Notifications
You must be signed in to change notification settings - Fork 887
/
sheets_pivot_tables.py
114 lines (105 loc) Β· 3.79 KB
/
sheets_pivot_tables.py
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
"""
Copyright 2022 Google LLC
Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at
http://www.apache.org/licenses/LICENSE-2.0
Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
"""
# [START sheets_pivot_tables]
import google.auth
from googleapiclient.discovery import build
from googleapiclient.errors import HttpError
def pivot_tables(spreadsheet_id):
"""
Creates the batch_update the user has access to.
Load pre-authorized user credentials from the environment.
TODO(developer) - See https://developers.google.com/identity
for guides on implementing OAuth2 for the application.
"""
creds, _ = google.auth.default()
# pylint: disable=maybe-no-member
try:
service = build("sheets", "v4", credentials=creds)
# Create two sheets for our pivot table.
body = {"requests": [{"addSheet": {}}, {"addSheet": {}}]}
batch_update_response = (
service.spreadsheets()
.batchUpdate(spreadsheetId=spreadsheet_id, body=body)
.execute()
)
source_sheet_id = (
batch_update_response.get("replies")[0]
.get("addSheet")
.get("properties")
.get("sheetId")
)
target_sheet_id = (
batch_update_response.get("replies")[1]
.get("addSheet")
.get("properties")
.get("sheetId")
)
requests = []
requests.append(
{
"updateCells": {
"rows": {
"values": [
{
"pivotTable": {
"source": {
"sheetId": source_sheet_id,
"startRowIndex": 0,
"startColumnIndex": 0,
"endRowIndex": 20,
"endColumnIndex": 7,
},
"rows": [
{
"sourceColumnOffset": 1,
"showTotals": True,
"sortOrder": "ASCENDING",
},
],
"columns": [{
"sourceColumnOffset": 4,
"sortOrder": "ASCENDING",
"showTotals": True,
}],
"values": [{
"summarizeFunction": "COUNTA",
"sourceColumnOffset": 4,
}],
"valueLayout": "HORIZONTAL",
}
}
]
},
"start": {
"sheetId": target_sheet_id,
"rowIndex": 0,
"columnIndex": 0,
},
"fields": "pivotTable",
}
}
)
body = {"requests": requests}
response = (
service.spreadsheets()
.batchUpdate(spreadsheetId=spreadsheet_id, body=body)
.execute()
)
return response
except HttpError as error:
print(f"An error occurred: {error}")
return error
if __name__ == "__main__":
# Pass: spreadsheet_id
pivot_tables("1CM29gwKIzeXsAppeNwrc8lbYaVMmUclprLuLYuHog4k")
# [END sheets_pivot_tables]